diff --git a/603.html b/603.html new file mode 100644 index 0000000..c57775b --- /dev/null +++ b/603.html @@ -0,0 +1,28 @@ +Part One Introduction
+Chapter 1: Introduction to PL/SQL
+
+Part Two Non-Object-Oriented Features in PL/SQL 9i
+Chapter 2: Cursors
+Chapter 3: PL/SQL Records and Index-by Tables
+Chapter 4: Error Message Handling
+Chapter 5: Stored Subprograms (Procedures, Functions, and Packages)
+Chapter 6: Database Triggers
+Chapter 7: Native Dynamic SQL and Dynamic PL/SQL
+Chapter 8: Autonomous Transactions
+Chapter 9: Native Bulk Binds
+
+Part Three Object-Oriented Features in PL/SQL 9i
+Chapter 10: The World of Objects
+Chapter 11: Collections (VARRAYS and Nested Tables)
+Chapter 12: Large Objects
+
+Part Four PL/SQL with Java and the Web
+Chapter 13: Floating in Java
+Chapter 14: PL/SQL and the Web
+
+Part Five PL/SQL Performance and Standards
+Chapter 15: Performance Considerations
+Chapter 16: PL/SQL Coding Standards
+
+Part Six Appendix
+Appendix A Case Studies and Schema Objects \ No newline at end of file diff --git a/735.pdf b/735.pdf new file mode 100644 index 0000000..ab0654a Binary files /dev/null and b/735.pdf differ diff --git a/737.pdf b/737.pdf new file mode 100644 index 0000000..cf24af7 Binary files /dev/null and b/737.pdf differ diff --git a/9781590590492.jpg b/9781590590492.jpg new file mode 100644 index 0000000..2c2f9b2 Binary files /dev/null and b/9781590590492.jpg differ diff --git a/AppendixA/AppendixA.txt b/AppendixA/AppendixA.txt new file mode 100644 index 0000000..822480c --- /dev/null +++ b/AppendixA/AppendixA.txt @@ -0,0 +1,177 @@ +connect system/manager@ORCL; +create user plsql9i identified by plsql9i; +grant connect,resource,dba to plsql9i; + +connect plsql9i/plsql9i@ORCL; + +CREATE TABLE items_tab (item_code varchar2(6) PRIMARY KEY, + item_descr varchar2(20) NOT NULL); + +CREATE TABLE employee_test +(empid number(10) PRIMARY KEY, + lastname varchar2(30) NOT NULL, + firstname varchar2(30) NOT NULL, + middle_initial varchar2(2)); + +begin + insert into employee_test values (101,'SMITH','JOHN',null); + insert into employee_test values (102,'JOHNSON','ROBERT','L'); + insert into employee_test values (103,'LAKSHMAN','BULUSU',null); + insert into employee_test values (104,'KNOP','VICTORIA','A'); + commit; +end; +/ + +-- Organizational Hierarchy System +create table site_tab +(site_no number(4) not null, + site_descr varchar2(20) not null); + +alter table site_tab add primary key (site_no); + +create table hrc_tab +(hrc_code number(4) not null, + hrc_descr varchar2(20) not null); + +alter table hrc_tab add primary key (hrc_code); + +create table org_tab +(hrc_code number(4) not null, + org_id NUMBER(8) not null, + org_short_name varchar2(30) not null, + org_long_name varchar2(60)); + +alter table org_tab add sprimary key (hrc_code,org_id); +alter table org_tab add constraint org_tab_uk unique (org_id); +alter table org_tab +add constraint org_tab_fk foreign key (hrc_code)references hrc_tab(hrc_code); + +create table org_site_tab +(org_id number(8) not null, + site_no number(4) not null ); + +alter table org_site_tab add primary key (org_id,site_no); +alter table org_site_tab +add constraint org_site_tab_fk1 foreign key (org_id)references org_tab(org_id); +alter table org_site_tab +add constraint org_site_tab_fk2 foreign key (site_no) +references site_tab(site_no); + +create table org_level +(org_id number(8) not null, + org_level varchar2(1) not null); + +alter table org_level add primary key (org_id); +alter table org_level +add constraint org_level_fk foreign key (org_id)references org_tab(org_id); +alter table org_level +add constraint org_level_ck CHECK (org_level IN ('C','E','M','L')); + +create table sec_hrc_tab +(hrc_code number(4) not null, + hrc_descr varchar2(20) not null); + +create table sec_hrc_org_tab +(hrc_code number(4) not null, + hrc_descr varchar2(20) not null, + org_id NUMBER(8) not null, + org_short_name varchar2(30) not null, + org_long_name varchar2(60)); + +create table sec_hrc_audit +(hrc_code number(4) not null, + num_rows number(8) not null ); + +create sequence hrc_org_seq minvalue 1; + +insert into site_tab values (1,'New York'); +insert into site_tab values (2,'Washington'); +insert into site_tab values (3,'Chicago'); +insert into site_tab values (4,'Dallas'); +insert into site_tab values (5,'San Francisco'); + +insert into hrc_tab values (1,'CEO/COO'); +insert into hrc_tab values (2,'VP'); +insert into hrc_tab values (3,'Director'); +insert into hrc_tab values (4,'Manager'); +insert into hrc_tab values (5,'Analyst'); + +insert into org_tab values +(1,1001,'Office of CEO ABC Inc.','Office of CEO ABC Inc.'); +insert into org_tab values +(1,1002,'Office of CEO XYZ Inc.','Office of CEO XYZ Inc.'); +insert into org_tab values +(1,1003,'Office of CEO DataPro Inc.','Office of CEO DataPro Inc.'); +insert into org_tab values +(2,1004,'Office of VP Sales ABC Inc.','Office of VP Sales ABC Inc.'); +insert into org_tab values +(2,1005,'Office of VP Mktg ABC Inc.','Office of VP Mktg ABC Inc.'); +insert into org_tab values +(2,1006,'Office of VP Tech ABC Inc.','Office of VP Tech ABC Inc.'); + +insert into org_site_tab values (1001,1); +insert into org_site_tab values (1002,2); +insert into org_site_tab values (1003,3); +insert into org_site_tab values (1004,1); +insert into org_site_tab values (1004,2); +insert into org_site_tab values (1004,3); +insert into org_site_tab values (1005,1); +insert into org_site_tab values (1005,4); +insert into org_site_tab values (1005,5); +insert into org_site_tab values (1006,1); + +-- Order Entry Application System + +CREATE TABLE region_tab +(region_id NUMBER(4) PRIMARY KEY, +region_name VARCHAR2(11) NOT NULL); + +CREATE TABLE region_tab_temp AS + SELECT *FROM region_tab; + +CREATE TABLE sec_region_tab +(region_id NUMBER(4) PRIMARY KEY, +region_name VARCHAR2(11) NOT NULL); + +CREATE TABLE supplier_tab +(supp_id NUMBER(6) PRIMARY KEY, + supp_name VARCHAR2(20) NOT NULL +); + +CREATE TABLE order_tab +(order_id NUMBER(10) PRIMARY KEY, +order_date DATE NOT NULL, +total_qty NUMBER, +total_price NUMBER(15,2), +supp_id NUMBER(6) REFERENCES supplier_tab(supp_id)); + +CREATE TABLE order_items +(order_id NUMBER(10) NOT NULL, +item_id VARCHAR2(10) NOT NULL, +unit_price NUMBER(11,2) NOT NULL, +quantity NUMBER); + +ALTER TABLE order_items ADD CONSTRAINT pk_order_items +PRIMARY KEY (order_id,item_id); + +CREATE TABLE error_log +(order_id NUMBER(10) NOT NULL, +error_code NUMBER NOT NULL, +error_text VARCHAR2(1000) NOT NULL, +logged_user VARCHAR2(30) NOT NULL, +logged_date DATE NOT NULL); + +CREATE TABLE order_tran_coming_in +(order_id NUMBER(10) NOT NULL, +order_date DATE NOT NULL, +tran_coming_in_date DATE NOT NULL, +success_flag VARCHAR2(1) DEFAULT 'N' NOT NULL); + +INSERT INTO region_tab VALUES (1,'REGION1'); +INSERT INTO region_tab VALUES (2,'REGION2'); +INSERT INTO region_tab VALUES (3,'REGION3'); +INSERT INTO region_tab VALUES (4,'REGION4'); + +INSERT INTO supplier_tab VALUES (1001,'Supplier 1001'); + +INSERT INTO order_tab VALUES (101,sysdate,100,750,1001); diff --git a/Chapter01/Chapter01.txt b/Chapter01/Chapter01.txt new file mode 100644 index 0000000..2a4935d --- /dev/null +++ b/Chapter01/Chapter01.txt @@ -0,0 +1,120 @@ +Listing 1-1. A Sample PL/SQL Block + +DECLARE + v_item_code VARCHAR2(6); + v_item_descr VARCHAR2(20); +BEGIN + v_item_code :='ITM101'; + v_item_descr :='Spare parts'; + INSERT INTO items_tab VALUES (v_item_code,v_item_descr); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); +END; +/ + + +Listing 1-2. The Modified PL/SQL Code That Uses a Nested Block + +DECLARE + v_item_code VARCHAR2(6); + v_item_descr VARCHAR2(20); + v_num NUMBER(1); +BEGIN + v_item_code :='ITM101'; + v_item_descr :='Spare parts'; + BEGIN + SELECT 1 + INTO v_num + FROM items_tab + WHERE item_code =v_item_code; + EXCEPTION + WHEN NO_DATA_FOUND THEN + v_num :=0; + WHEN OTHERS THEN + dbms_output.put_line('Error in SELECT:'||SQLERRM); + RETURN; + END; + IF (v_num =0)THEN + INSERT INTO items_tab VALUES (v_item_code,v_item_descr); + END IF; + dbms_output.put_line('Successful Completion'); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); +END; +/ + +-- An example of the IF statement +DECLARE + a number :=50; + b number :=-20; +BEGIN + IF (a>b)THEN + dbms_output.put_line('A is greater than B'); + ELSIF (ab)then 'A is greater than B' + when (a...*/ + null; +END; +/ + +-- An example of opening the csr_org cursor +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); +BEGIN + OPEN csr_org; + /*......*/ + null; +END; +/ + +-- An example of csr_org to fetching rows +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); +BEGIN + OPEN csr_org; + FETCH csr_org INTO v_hrc_descr,v_org_short_name; + --This fetch fetches the first row in the active set. + null; +END; +/ + +-- An example of using cursor_name%RWOTYPE +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + OPEN csr_org; + FETCH csr_org INTO v_org_rec; + --This fetch fetches the first row in the active set. + null; +END; +/ + +-- A complete example of using the csr_org cursor +DECLARE + /*Declare a cursor explicitly */ + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + /*Open the cursor */ + OPEN csr_org; + /*Format headings */ + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + /*Fetch from the cursor resultset in a loop and display the results + */ + LOOP + FETCH csr_org INTO v_org_rec; + EXIT WHEN csr_org%NOTFOUND; + dbms_output.put_line(rpad(v_org_rec.hrc_descr,20,' ')||' '|| + rpad(v_org_rec.org_short_name,30,' ')); + END LOOP; + /*CLose the cursor */ + CLOSE csr_org; +END; +/ + +-- A complete example of using the csr_org cursor +-- using a WHILE LOOP +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + OPEN csr_org; + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FETCH csr_org INTO v_org_rec; + WHILE (csr_org%FOUND) LOOP + dbms_output.put_line(rpad(v_org_rec.hrc_descr,20,' ')||' '|| + rpad(v_org_rec.org_short_name,30,' ')); + FETCH csr_org INTO v_org_rec; + END LOOP; + CLOSE csr_org; +END; +/ + +-- A complete example if uisng the csr_org cursor +-- using a cursor FOR LOOP +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; +BEGIN + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FOR idx IN csr_org LOOP + dbms_output.put_line(rpad(idx.hrc_descr,20,' ')||' '|| + rpad(idx.org_short_name,30,' ')); + END LOOP; +END; +/ + +-- An example of csr_org cursor using %ISOPEN +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + IF (NOT csr_org%ISOPEN) THEN + OPEN csr_org; + END IF; + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FETCH csr_org INTO v_org_rec; + WHILE (csr_org%FOUND)LOOP + dbms_output.put_line(rpad(v_org_rec.hrc_descr,20,' ')||' '|| + rpad(v_org_rec.org_short_name,30,' ')); + FETCH csr_org INTO v_org_rec; + END LOOP; + IF (csr_org%ISOPEN)THEN + CLOSE csr_org; + END IF; +END; +/ + +-- An example of csr_org cursor using %ROWCOUNT +DECLARE + CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + num_total_rows NUMBER; +BEGIN + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FOR idx IN csr_org LOOP + dbms_output.put_line(rpad(idx.hrc_descr,20,' ')||' '|| + rpad(idx.org_short_name,30,' ')); + num_total_rows :=csr_org%ROWCOUNT; + END LOOP; + IF num_total_rows >0 THEN + dbms_output.new_line; + dbms_output.put_line('Total Organizations = '||to_char(num_total_rows)); + END IF; +END; +/ + +-- An examplre of csr_org cursor using %ROWCOUNT +-- as an incremental rowcount +DECLARE +CURSOR csr_org IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + ORDER by 2; + num_total_rows NUMBER; +BEGIN + FOR idx IN csr_org LOOP + IF csr_org%ROWCOUNT =1 THEN + dbms_output.put_line('Organization Details with Hierarchy'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + END IF; + dbms_output.put_line(rpad(idx.hrc_descr,20,' ')||' '|| + rpad(idx.org_short_name,30,' ')); + num_total_rows :=csr_org%ROWCOUNT; + END LOOP; + IF num_total_rows >0 THEN + dbms_output.new_line; + dbms_output.put_line('Total Organizations = '||to_char(num_total_rows)); + END IF; +END; +/ + +-- An example to illustrate parameterized cursors +DECLARE + CURSOR csr_org(p_hrc_code NUMBER) IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =p_hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + OPEN csr_org(1); + dbms_output.put_line('Organization Details with Hierarchy 1'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + LOOP + FETCH csr_org INTO v_org_rec; + EXIT WHEN csr_org%NOTFOUND; + dbms_output.put_line(rpad(v_org_rec.hrc_descr,20,' ')||' '|| + rpad(v_org_rec.org_short_name,30,' ')); + END LOOP; + CLOSE csr_org; + OPEN csr_org(2); + dbms_output.put_line('Organization Details with Hierarchy 2'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + LOOP + FETCH csr_org INTO v_org_rec; + EXIT WHEN csr_org%NOTFOUND; + dbms_output.put_line(rpad(v_org_rec.hrc_descr,20,' ')||' '|| + rpad(v_org_rec.org_short_name,30,' ')); + END LOOP; + CLOSE csr_org; +END; +/ + +-- An example of parameterized cursor using cursor FOR LOOP +DECLARE + CURSOR csr_org(p_hrc_code NUMBER) IS + SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =p_hrc_code + ORDER by 2; + v_org_rec csr_org%ROWTYPE; +BEGIN + dbms_output.put_line('Organization Details with Hierarchy 1'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')|| + ''||rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FOR idx in csr_org(1) LOOP + dbms_output.put_line(rpad(idx.hrc_descr,20,' ')||' '|| + rpad(idx.org_short_name,30,' ')); + END LOOP; + dbms_output.put_line('Organization Details with Hierarchy 2'); + dbms_output.put_line('------------------------');; + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + FOR idx in csr_org(2) LOOP + dbms_output.put_line(rpad(idx.hrc_descr,20,' ')||' '|| + rpad(idx.org_short_name,30,' ')); + END LOOP; +END; +/ + +-- A complete example of using SELECT FOR UPDATE cursors +BEGIN + INSERT INTO sec_hrc_tab + SELECT *FROM hrc_tab; + COMMIT; +END; +/ +DECLARE + CURSOR csr_1 IS + SELECT * FROM sec_hrc_tab FOR UPDATE OF hrc_descr; + v_hrc_descr VARCHAR2(20); +BEGIN + FOR idx IN csr_1 LOOP + v_hrc_descr :=UPPER(idx.hrc_descr); + UPDATE sec_hrc_tab + SET hrc_descr =v_hrc_descr + WHERE CURRENT OF csr_1; + END LOOP; + COMMIT; +END; +/ + +-- An example of an implicit cursor +BEGIN + DELETE sec_hrc_org_tab WHERE hrc_code =1; + INSERT INTO sec_hrc_org_tab + SELECT h.hrc_code,h.hrc_descr, + o.org_id,o.org_short_name,o.org_long_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =1; + IF (SQL%FOUND)THEN + dbms_output.put_line(TO_CHAR(SQL%ROWCOUNT)|| + 'rows inserted into secondary table for hierarchy 1'); + END IF; + COMMIT; +END; +/ + +-- An example of using SQL%NOTFOUND +DECLARE + v_num_rows NUMBER; +BEGIN + DELETE sec_hrc_org_tab WHERE hrc_code =1; + INSERT INTO sec_hrc_org_tab + SELECT h.hrc_code,h.hrc_descr, + o.org_id,o.org_short_name,o.org_long_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =1; + v_num_rows :=SQL%ROWCOUNT; + IF (SQL%FOUND)THEN + UPDATE sec_hrc_audit + SET num_rows =v_num_rows + WHERE hrc_code =1; + IF (SQL%NOTFOUND)THEN + INSERT INTO sec_hrc_audit(hrc_code,num_rows)VALUES (1,v_num_rows); + END IF; + END IF; + COMMIT; +END; +/ + +-- An example of using SQL%ROWCOUNT +DECLARE + v_num_rows NUMBER; +BEGIN + DELETE sec_hrc_org_tab WHERE hrc_code =1; + INSERT INTO sec_hrc_org_tab + SELECT h.hrc_code,h.hrc_descr, + o.org_id,o.org_short_name,o.org_long_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =1; + v_num_rows :=SQL%ROWCOUNT; + IF (SQL%FOUND)THEN + UPDATE sec_hrc_audit + SET num_rows =v_num_rows + WHERE hrc_code =1; + IF (SQL%ROWCOUNT=0)THEN + INSERT INTO sec_hrc_audit(hrc_code,num_rows)VALUES (1,v_num_rows); + END IF; + END IF; + COMMIT; +END; +/ + +-- An example of opening a cursor variable +DECLARE + TYPE rc is REF CURSOR; + v_rc rc; +BEGIN + OPEN v_rc FOR SELECT *from hrc_tab; + /*...FETCH the results and process the resultset */ + null; +END; +/ + +-- An example of fetching from a cursor variable +DECLARE + TYPE rc is REF CURSOR; + v_rc rc; + hrc_rec hrc_tab%ROWTYPE; +BEGIN + OPEN v_rc FOR SELECT *from hrc_tab; + LOOP + FETCH v_rc INTO hrc_rec; + EXIT WHEN v_rc%NOTFOUND; + /*...Process the individual records */ + null; + END LOOP; +END; +/ + +-- A complete example of using a cursor variable +DECLARE + TYPE rc is REF CURSOR; + v_rc rc; + hrc_rec hrc_tab%ROWTYPE; +BEGIN + OPEN v_rc FOR SELECT *from hrc_tab; + dbms_output.put_line('Hierarchy Details'); + dbms_output.put_line('------------------------'); + dbms_output.put_line('Code'||' '||rpad('Description',20,' ')); + dbms_output.put_line(rpad('-',4,'-')||' '||rpad('-',20,'-')); + LOOP + FETCH v_rc INTO hrc_rec; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '|| + rpad(hrc_rec.hrc_descr,20,' ')); + END LOOP; + CLOSE v_rc; +END; +/ + +-- An example of cursor variable assignment +DECLARE + TYPE rc is REF CURSOR; + v_rc1 rc; + v_rc2 rc; + hrc_rec hrc_tab%ROWTYPE; +BEGIN + OPEN v_rc1 FOR SELECT *from hrc_tab; + dbms_output.put_line('Hierarchy Details'); + dbms_output.put_line('------------------------'); + dbms_output.put_line('Code'||' '||rpad('Description',20,' ')); + dbms_output.put_line(rpad('-',4,'-')||' '||rpad('-',20,'-')); + /*Assign v_rc1 to v_rc2 */ + v_rc2 :=v_rc1; + LOOP + /*Fetch from the second cursor variable,i.e.,v_rc2 */ + FETCH v_rc2 INTO hrc_rec; + EXIT WHEN v_rc2%NOTFOUND; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '|| + rpad(hrc_rec.hrc_descr,20,' ')); + END LOOP; + CLOSE v_rc2; +END; +/ + +-- An example of using SYS_REFCURSOR for +-- cursor variable processing +DECLARE + v_rc SYS_REFCURSOR; + hrc_rec hrc_tab%ROWTYPE; +BEGIN + OPEN v_rc FOR SELECT *from hrc_tab; + dbms_output.put_line('Hierarchy Details'); + dbms_output.put_line('------------------------'); + dbms_output.put_line('Code'||' '||rpad('Description',20,' ')); + dbms_output.put_line(rpad('-',4,'-')||' '||rpad('-',20,'-')); + LOOP + FETCH v_rc INTO hrc_rec; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '|| + rpad(hrc_rec.hrc_descr,20,' ')); + END LOOP; + CLOSE v_rc; +END; +/ + +-- Opening multiple queries using the same cursor variable +DECLARE + TYPE rc is REF CURSOR; + v_rc rc; + hrc_rec hrc_tab%ROWTYPE; + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); +BEGIN + OPEN v_rc FOR SELECT *from hrc_tab; + dbms_output.put_line('Hierarchy Details'); + dbms_output.put_line('------------------------'); + dbms_output.put_line('Code'||' '||rpad('Description ',20,' ')); + dbms_output.put_line(rpad('-',4,'-')||' '||rpad('-',20,'-')); + LOOP + FETCH v_rc INTO hrc_rec; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '|| + rpad(hrc_rec.hrc_descr,20,' ')); + END LOOP; + OPEN v_rc FOR SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code; + dbms_output.put_line('Hierarchy and Organization Details'); + dbms_output.put_line('------------------------'); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Description',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + LOOP + FETCH v_rc INTO v_hrc_descr,v_org_short_name; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(rpad(v_hrc_descr,20,' ')||' '|| + rpad(v_org_short_name,30,' ')); + END LOOP; + CLOSE v_rc; +END; +/ + +-- Assigning different queries to the same cursor variable +CREATE OR REPLACE PROCEDURE p_print_report(p_report_no NUMBER,p_title VARCHAR2) +IS + TYPE rc IS REF CURSOR; + v_rc rc; + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); +BEGIN + IF (p_report_no =1)THEN + OPEN v_rc FOR SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND 1 < (SELECT count(os.site_no) + FROM org_site_tab os + WHERE os.org_id =o.org_id); + ELSIF (p_report_no =2)THEN + OPEN v_rc FOR SELECT h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND NOT EXISTS + (SELECT * + FROM org_tab o1 + WHERE o1.org_id =o.org_id + AND o1.hrc_code =2 ); + END IF; + dbms_output.put_line(p_title); + dbms_output.put_line(rpad('-',length(p_title),'-')); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Description',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + LOOP + FETCH v_rc INTO v_hrc_descr,v_org_short_name; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(rpad(v_hrc_descr,20,' ')||' '|| + rpad(v_org_short_name,30,' ')); + END LOOP; + CLOSE v_rc; +END p_print_report; +/ + +-- A PL/SQL function that uses a cursor expression +create or replace function f_cursor_exp return NUMBER +is + TYPE rc is REF CURSOR; + /*declare the cursor expression */ + CURSOR csr_hierarchy IS + SELECT h.hrc_descr, + CURSOR(SELECT o.org_long_name + FROM org_tab o + WHERE o.hrc_code =h.hrc_code)long_name + FROM hrc_tab h; + /*Declare a REF CURSOR variable to hold the nested cursor resultset + while fetching.*/ + hrc_rec rc; + v_hrc_descr VARCHAR2(20); + v_org_long_name VARCHAR2(60); +BEGIN + /*Open the parent cursor */ + OPEN csr_hierarchy; + LOOP + /*fetch the column csr_hierarchy.hrc_descr, + then loop through the resultset of the nested cursor.*/ + FETCH csr_hierarchy INTO v_hrc_descr,hrc_rec; + EXIT WHEN csr_hierarchy%notfound; + /*Use a nested loop that fetches from the nested cursor + within the parent rows.*/ + LOOP + --Directly fetch from the nested cursor,there is no need to open it. + FETCH hrc_rec INTO v_org_long_name; + EXIT WHEN hrc_rec%notfound; + DBMS_OUTPUT.PUT_LINE(v_hrc_descr ||''||v_org_long_name); + END LOOP; + END LOOP; + /*Close the parent cursor.No need to close the nested cursor.*/ + close csr_hierarchy; + RETURN (0); +EXCEPTION WHEN OTHERS THEN + RETURN (SQLCODE); +END; +/ + +-- Cursor expressions using multiple levels of nested cursors +create or replace function f_cursor_exp_complex return NUMBER +is + TYPE rc is REF CURSOR; + /*declare the cursor expression */ + CURSOR csr_hierarchy IS + SELECT h.hrc_descr, + CURSOR(SELECT o.org_long_name, + CURSOR (SELECT s.site_descr + FROM org_site_tab os,site_tab s + WHERE os.site_no =s.site_no + AND os.org_id =o.org_id)as site_name + FROM org_tab o + WHERE o.hrc_code =h.hrc_code)long_name + FROM hrc_tab h; + /*Declare two REF CURSOR variables to hold the nested cursor resultset + while fetching.*/ + hrc_rec rc; + org_rec rc; + v_hrc_descr VARCHAR2(20); + v_org_long_name VARCHAR2(60); + v_site_name VARCHAR2(20); +BEGIN + /*Open the parent cursor */ + OPEN csr_hierarchy; + LOOP + /*fetch the column csr_hierarchy.hrc_descr, + then loop through the resultset of the nested cursors.*/ + FETCH csr_hierarchy INTO v_hrc_descr,hrc_rec; + EXIT WHEN csr_hierarchy%notfound; + LOOP + /*Use a nested loop that fetches from the first nested cursor + within the parent rows */ + FETCH hrc_rec INTO v_org_long_name,org_rec; + EXIT WHEN hrc_rec%notfound; + LOOP + --Directly fetch from the second nested cursor,there is no need to open it + FETCH org_rec INTO v_site_name; + EXIT WHEN org_rec%notfound; + DBMS_OUTPUT.PUT_LINE(v_hrc_descr ||''||v_org_long_name||''|| + v_site_name); + END LOOP; + END LOOP; + END LOOP; + /*Close the parent cursor.No need to close the nested cursor.*/ + close csr_hierarchy; + RETURN (0); +EXCEPTION WHEN OTHERS THEN + RETURN (SQLCODE); +END; +/ + +-- Cursor expressions as arguments to functions called from SQL +CREATE OR REPLACE FUNCTION f_report(p_cursor SYS_REFCURSOR,p_title VARCHAR2) +RETURN NUMBER +IS + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); + v_ret_code NUMBER; +BEGIN + BEGIN + dbms_output.put_line(p_title); + dbms_output.put_line(rpad('Hierarchy',20,' ')||' '|| + rpad('Organization',30,' ')); + dbms_output.put_line(rpad('-',20,'-')||' '||rpad('-',30,'-')); + LOOP + FETCH p_cursor INTO v_hrc_descr,v_org_short_name; + EXIT WHEN p_cursor%NOTFOUND; + dbms_output.put_line(rpad(v_hrc_descr,20,' ')||' '|| + rpad(v_org_short_name,30,' ')); + END LOOP; + v_ret_code :=1; + EXCEPTION WHEN OTHERS THEN + v_ret_code :=SQLCODE; + END; + RETURN (v_ret_code); +END; +/ +CREATE OR REPLACE PROCEDURE flush +IS +BEGIN + NULL; +END; +/ +SELECT 'Report Generated on '||TO_CHAR(SYSDATE,'MM/DD/YYYY ') "Report1" +FROM DUAL +WHERE f_report( + CURSOR(SELECT h.hrc_descr,o.org_short_name + FROM hrc_tab h,org_tab o + WHERE o.hrc_code =h.hrc_code + AND 1 < (SELECT count(os.site_no) + FROM org_site_tab os + WHERE os.org_id =o.org_id) + ), + 'List of Organizations located in more than one site' +)=1; +SELECT 'Report Generated on '||TO_CHAR(SYSDATE,'MM/DD/YYYY ') "Report2" +FROM DUAL +WHERE f_report( + CURSOR(SELECT h.hrc_descr,o.org_short_name + FROM hrc_tab h,org_tab o + WHERE o.hrc_code =h.hrc_code + AND NOT EXISTS (SELECT * + FROM org_tab o1 + WHERE o1.org_id =o.org_id + AND o1.hrc_code = 2 + ) + ),'List of Organizations not having a VP' +)=1; +CREATE OR REPLACE FUNCTION f_cursor(p_cursor SYS_REFCURSOR) +RETURN NUMBER +IS + v_org_short_name VARCHAR2(30); + v_cnt NUMBER :=0; + v_ret_code NUMBER; +BEGIN + BEGIN + LOOP + FETCH p_cursor INTO v_org_short_name; + EXIT WHEN p_cursor%NOTFOUND; + v_cnt :=v_cnt +1; + END LOOP; + IF (v_cnt >0)THEN + v_ret_code :=1; + ELSE + v_ret_code :=0; + END IF; + EXCEPTION WHEN OTHERS THEN + v_ret_code :=SQLCODE; + END; + RETURN (v_ret_code); +END; +/ +SELECT rpad(h.hrc_descr,20,' ') "Hierarchy", + rpad(o.org_short_name,30,' ') "Organization" +FROM hrc_tab h,org_tab o +WHERE h.hrc_code =o.hrc_code +AND f_cursor( + CURSOR(SELECT o1.org_short_name + FROM org_tab o1 + WHERE o1.org_id =o.org_id + AND 1 < (SELECT count(os.site_no) + FROM org_site_tab os + WHERE os.org_id =o1.org_id) + ) +)=1; +SELECT rpad(h.hrc_descr,20,' ') "Hierarchy", + rpad(o.org_short_name,30,' ') "Organization" +FROM hrc_tab h,org_tab o +WHERE h.hrc_code =o.hrc_code +AND f_cursor( + CURSOR(SELECT o1.org_short_name + FROM org_tab o1 + WHERE o1.org_id =o.org_id + AND NOT EXISTS (SELECT * + FROM org_tab o2 + WHERE o2.org_id =o1.org_id + AND o2.hrc_code =2) + ) +)=1; diff --git a/Chapter03/Chapter03.txt b/Chapter03/Chapter03.txt new file mode 100644 index 0000000..11bd23f --- /dev/null +++ b/Chapter03/Chapter03.txt @@ -0,0 +1,422 @@ +-- An example of declaring a record +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec hrc_org_rec; +BEGIN + /*Do some processing */ + null; +END; +/ + +-- Accessing Individual Record elements +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec hrc_org_rec; +BEGIN + v_example_rec.hrc_org_id :=1001; + v_example_rec.hrc_descr :='CEO/COO'; + v_example_rec.org_short_name :='Office of CEO/COO ABC Inc.'; + dbms_output.put_line('An example record:'); + dbms_output.new_line; + dbms_output.put_line(to_number(v_example_rec.hrc_org_id)||' '|| + v_example_rec.hrc_descr||' '|| + v_example_rec.org_short_name); +END; +/ + +-- Accessing an entire record +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec1 hrc_org_rec; + v_example_rec2 hrc_org_rec; +BEGIN + v_example_rec1.hrc_org_id :=1001; + v_example_rec1.hrc_descr :='CEO/COO'; + v_example_rec1.org_short_name :='Office of CEO/COO ABC Inc.'; + v_example_rec2 :=v_example_rec1; + dbms_output.put_line('An example record:'); + dbms_output.new_line; + dbms_output.put_line(to_number(v_example_rec2.hrc_org_id)||' '|| + v_example_rec2.hrc_descr||' '|| + v_example_rec2.org_short_name); +END; +/ + +-- Testing for equality of records +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec1 hrc_org_rec; + v_example_rec2 hrc_org_rec; +BEGIN + v_example_rec1.hrc_org_id :=1001; + v_example_rec1.hrc_descr :='CEO/COO'; + v_example_rec1.org_short_name :='Office of CEO/COO ABC Inc.'; + v_example_rec2.hrc_org_id :=1002; + v_example_rec2.hrc_descr :='VP '; + v_example_rec2.org_short_name :='Office of VP ABC Inc.'; + IF ((v_example_rec1.hrc_org_id =v_example_rec2.hrc_org_id) AND + (v_example_rec1.hrc_descr =v_example_rec2.hrc_descr) AND + (v_example_rec1.org_short_name =v_example_rec2.org_short_name)) THEN + dbms_output.put_line('Both example records are identical.'); + ELSE + dbms_output.put_line('The two example records are different.'); + END IF; +END; +/ + +-- Populating a Record with SELECT INTO +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec hrc_org_rec; +BEGIN + SELECT hrc_org_seq.nextval,h.hrc_descr,o.org_short_name + INTO v_example_rec + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND o.org_id =1001; + dbms_output.put_line('An example record:'); + dbms_output.new_line; + dbms_output.put_line(to_number(v_example_rec.hrc_org_id)||' '|| + v_example_rec.hrc_descr||' '|| + v_example_rec.org_short_name); +END; +/ + +-- Populating a Record with FETCH INTO +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + v_example_rec hrc_org_rec; + CURSOR csr_hrc_org IS + SELECT hrc_org_seq.nextval,h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =1; +BEGIN + OPEN csr_hrc_org; + dbms_output.put_line('An example output:'); + dbms_output.new_line; + LOOP + FETCH csr_hrc_org INTO v_example_rec; + EXIT WHEN csr_hrc_org%NOTFOUND; + dbms_output.put_line(to_number(v_example_rec.hrc_org_id)||' '|| + v_example_rec.hrc_descr||' '|| + v_example_rec.org_short_name); + END LOOP; + CLOSE csr_hrc_org; +END; +/ + +-- Defining and using a table-oriented record +DECLARE + hrc_rec hrc_tab%ROWTYPE; +BEGIN + SELECT * + INTO hrc_rec + FROM hrc_tab + WHERE hrc_code =1; + dbms_output.put_line('An example record:'); + dbms_output.new_line; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '||hrc_rec.hrc_descr); +END; +/ + +-- Defining and using a cursor-oriented record +DECLARE + CURSOR csr_hrc IS + SELECT *FROM hrc_tab ORDER BY 1; + hrc_rec csr_hrc%ROWTYPE; +BEGIN + OPEN csr_hrc; + dbms_output.put_line('Hierarchy records:'); + dbms_output.new_line; + LOOP + FETCH csr_hrc INTO hrc_rec; + EXIT WHEN csr_hrc%NOTFOUND; + dbms_output.put_line(to_char(hrc_rec.hrc_code)||' '||hrc_rec.hrc_descr); + END LOOP; + CLOSE csr_hrc; +END; +/ + +-- INSERT statement involving entire records +DECLARE + TYPE hrc_rec IS RECORD + (hrc_code NUMBER, + hrc_descr VARCHAR2(20)); + v_example_rec hrc_rec; +BEGIN + v_example_rec.hrc_code :=99; + v_example_rec.hrc_descr :='Web Analyst'; + INSERT INTO hrc_tab VALUES v_example_rec; + COMMIT; +END; +/ + +-- UPDATE statement involving entire records +DECLARE + TYPE hrc_rec IS RECORD + (hrc_code NUMBER, + hrc_descr VARCHAR2(20)); + v_example_rec hrc_rec; +BEGIN + v_example_rec.hrc_code :=99; + v_example_rec.hrc_descr :='Web Analyst Sr.'; + UPDATE hrc_tab SET ROW =v_example_rec WHERE hrc_code =99; + COMMIT; +END; +/ + +-- An example of declaring an Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; +BEGIN + /*Do some processing */ + null; +END; +/ + +-- Accessing an Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab(1):=1001; + v_example_tab(10):=1002; + v_example_tab(-10):=1003; + v_example_tab(v_num):=1004; + dbms_output.put_line('An example array:'); + dbms_output.new_line; + dbms_output.put_line(to_char(v_example_tab(1))||' '|| + to_char(v_example_tab(10))||' '|| + to_char(v_example_tab(-10))||' '|| + to_char(v_example_tab(v_num))); +END; +/ + +-- Accessing an entire Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab1 num_tab; + v_example_tab2 num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab1(1):=1001; + v_example_tab1(10):=1002; + v_example_tab1(-10):=1003; + v_example_tab1(v_num):=1004; + v_example_tab2 :=v_example_tab1; + dbms_output.put_line('An example array:'); + dbms_output.new_line; + dbms_output.put_line(to_char(v_example_tab2(1))||' '|| + to_char(v_example_tab2(10))||' '|| + to_char(v_example_tab2(-10))||' '|| + to_char(v_example_tab2(v_num))); +END; +/ + +-- Accessing an undefined row of an Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab(1):=1001; + v_example_tab(10):=1002; + v_example_tab(-10):=1003; + v_example_tab(v_num):=1004; + dbms_output.put_line(to_char(v_example_tab(100))); +END; +/ + +-- Sample code using exception while accessing an undefined row of +-- an Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab(1):=1001; + v_example_tab(10):=1002; + v_example_tab(-10):=1003; + v_example_tab(v_num):=1004; + dbms_output.put_line(to_char(v_example_tab(100))); +EXCEPTION WHEN NO_DATA_FOUND THEN + dbms_output.put_line ('Invalid array element '); +END; +/ + +-- Assigning rows of an Index-By table by means of a LOOP +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; +BEGIN + FOR idx IN 1..10 LOOP + v_example_tab(idx):=(2**idx)+1; + END LOOP; + dbms_output.put_line('An example array:'); + dbms_output.new_line; + FOR idx IN 1..10 LOOP + dbms_output.put_line(to_char(v_example_tab(idx))); + END LOOP; +END; +/ + +-- Deleting an Index-by table using an empty Index-by table +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab1 num_tab; + v_example_tab2 num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab1(1):=1001; + v_example_tab1(10):=1002; + v_example_tab1(-10):=1003; + v_example_tab1(v_num):=1004; + v_example_tab1:=v_example_tab2; +END; +/ + +-- Using the EXISTS method +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; + v_num NUMBER :=13; +BEGIN + v_example_tab(1):=1001; + v_example_tab(10):=1002; + v_example_tab(-10):=1003; + v_example_tab(v_num):=1004; + IF v_example_tab.EXISTS(100) THEN + dbms_output.put_line(to_char(v_example_tab(100))); + END IF; +END; +/ + +-- An example of COUNT method +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; +BEGIN + FOR idx IN 1..10 LOOP + v_example_tab(idx):=(2**idx)+1; + END LOOP; + dbms_output.put_line('An example array:'); + dbms_output.new_line; + FOR idx IN 1..v_example_tab.COUNT LOOP + dbms_output.put_line(to_char(v_example_tab(idx))); + END LOOP; +END; +/ + +-- An example of the DELETE method +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; +BEGIN + FOR idx IN 1..10 LOOP + v_example_tab(idx):=(2**idx)+1; + END LOOP; + v_example_tab.DELETE(1); + v_example_tab.DELETE(2,5); + v_example_tab.DELETE; +END; +/ + +-- An example of the FIRST, LAST and NEXT methods +DECLARE + TYPE num_tab IS TABLE OF NUMBER INDEX BY BINARY_INTEGER; + v_example_tab num_tab; + idx BINARY_INTEGER; +BEGIN + FOR idx IN 1..10 LOOP + v_example_tab(idx):=(2**idx)+1; + END LOOP; + dbms_output.put_line('An example array:'); + dbms_output.new_line; + idx :=v_example_tab.FIRST; + LOOP + dbms_output.put_line(to_char(v_example_tab(idx))); + EXIT WHEN idx =v_example_tab.LAST; + idx :=v_example_tab.NEXT(idx); + END LOOP; +END; +/ + +-- Defining an Index-by table of records +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + TYPE hrc_org_tab IS TABLE OF hrc_org_rec INDEX BY BINARY_INTEGER; + v_example_tab hrc_org_tab; +BEGIN + /*Do some processing */ + null; +END; +/ + +-- Creating and accessing rows of an Index-by table of records +DECLARE + TYPE hrc_org_rec IS RECORD + (hrc_org_id NUMBER, + hrc_descr VARCHAR2(20), + org_short_name VARCHAR2(30)); + TYPE hrc_org_tab IS TABLE OF hrc_org_rec INDEX BY BINARY_INTEGER; + v_example_tab hrc_org_tab; + CURSOR csr_hrc_org IS + SELECT hrc_org_seq.nextval hrc_org_id,h.hrc_descr,o.org_short_name + FROM org_tab o,hrc_tab h + WHERE o.hrc_code =h.hrc_code + AND h.hrc_code =1; + i BINARY_INTEGER :=1; +BEGIN + FOR idx IN csr_hrc_org LOOP + v_example_tab(i).hrc_org_id :=idx.hrc_org_id; + v_example_tab(i).hrc_descr :=idx.hrc_descr; + v_example_tab(i).org_short_name :=idx.org_short_name; + i :=i +1; + END LOOP; + dbms_output.put_line('An example output:'); + dbms_output.new_line; + FOR j IN 1..v_example_tab.COUNT LOOP + dbms_output.put_line(to_char(v_example_tab(j).hrc_org_id)||' '|| + v_example_tab(j).hrc_descr||' '|| + v_example_tab(j).org_short_name); + END LOOP; +END; +/ + +-- Associative arrays +DECLARE + TYPE site_array IS TABLE OF NUMBER INDEX BY VARCHAR2(20); + v_example_array site_array; +BEGIN + v_example_array('Edison'):=10; + v_example_array('Bloomington'):=11; + v_example_array('Sunnyvale'):=12; + dbms_output.put_line(v_example_array.FIRST); + dbms_output.put_line(v_example_array.LAST); + dbms_output.put_line(TO_CHAR(v_example_array(v_example_array.FIRST))); +END; +/ diff --git a/Chapter04/Chapter04.txt b/Chapter04/Chapter04.txt new file mode 100644 index 0000000..47f6427 --- /dev/null +++ b/Chapter04/Chapter04.txt @@ -0,0 +1,258 @@ +-- An example showing handling of pre-defined exceptions +DECLARE + v_descr VARCHAR2(20); +BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =10; + dbms_output.put_line('The hierarchy description for code 10 is: '||v_descr); +EXCEPTION WHEN NO_DATA_FOUND THEN + dbms_output.put_line('ERR:Invalid Hierarchy Code 10'); +END; +/ + +-- The above example using WHEN OTHERS clause +DECLARE + v_descr VARCHAR2(20); +BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =10; + dbms_output.put_line('The hierarchy description for code 10 is: '||v_descr); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line('ERR:Invalid Hierarchy Code 10'); +END; +/ + +-- The previous example using NO_DATA_FOUND and WHEN OTEHRS +DECLARE + v_descr VARCHAR2(20); +BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =10; + dbms_output.put_line('The hierarchy description for code 10 is: '||v_descr); +EXCEPTION + WHEN NO_DATA_FOUND THEN + dbms_output.put_line('ERR:Invalid Hierarchy Code 10'); + WHEN OTHERS THEN + dbms_output.put_line('ERR:An error occurred'); +END; +/ + +-- The above example using SQLCODE and SQLERRM +DECLARE + v_descr VARCHAR2(20); +BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =10; + dbms_output.put_line('The hierarchy description for code 10 is: '||v_descr); +EXCEPTION + WHEN NO_DATA_FOUND THEN + dbms_output.put_line('ERR:Invalid Hierarchy Code 10'); + WHEN OTHERS THEN + dbms_output.put_line('ERR:An error occurred with info :'|| + TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- An example showing continuing program execution after handling exception +DECLARE + v_descr VARCHAR2(20); +BEGIN + BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =10; + dbms_output.put_line('The lowest hierarchy available is: Code 10 '||v_descr); + EXCEPTION WHEN NO_DATA_FOUND THEN + INSERT INTO hrc_tab VALUES (10,'Assistant'); + COMMIT; + END; + BEGIN + SELECT hrc_descr + INTO v_descr + FROM hrc_tab + WHERE hrc_code =1; + dbms_output.put_line('The highest hierarchy available is: Code 1 '|| + v_descr); + EXCEPTION WHEN NO_DATA_FOUND THEN + dbms_output.put_line('ERR:Invalid Data for Hierarchy'); + END; +EXCEPTION + WHEN OTHERS THEN + dbms_output.put_line('ERR:An error occurred with info :'|| + TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- Handling user-defined exceptions with a WHEN clause +BEGIN +insert into org_tab values + (3,1007,'Office of Dir Tech ABC Inc.','Office of Director Tech ABC Inc.'); +COMMIT; +END; +/ +DECLARE + sites_undefined_for_org EXCEPTION;-- a user-defined exception + v_cnt NUMBER; +BEGIN + SELECT COUNT(*) + INTO v_cnt + FROM org_site_tab + WHERE org_id =1007; + IF (v_cnt=0)THEN + --explicitly raising the user-defined exception + RAISE sites_undefined_for_org; + END IF; +EXCEPTION + --handling the raised user-defined exception + WHEN sites_undefined_for_org THEN + dbms_output.put_line('There are no sites defined for organization 1007'); + WHEN OTHERS THEN + dbms_output.pu t_line('ERR:An error occurred with info :'|| + TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- An example of using PRAGMA EXCEPTION_INIT +DECLARE + invalid_org_level EXCEPTION; + PRAGMA EXCEPTION_INIT(invalid_org_level,-2290); +BEGIN + INSERT INTO org_level VALUES (1001,'P'); + COMMIT; +EXCEPTION WHEN invalid_org_level THEN + dbms_output.put_line( + 'Organization Level can be only one of '|| + 'C –Corporate,E –Executive,M –Mid-level,L –Lower Level'); +END; +/ + +-- An example showing handling of exceptions raised in the +-- declaration section +BEGIN + DECLARE + v_num NUMBER(2):=100; + BEGIN + /*......Do some processing */ + null; + EXCEPTION + WHEN VALUE_ERROR THEN + /*......Handle the error */ + NULL; + WHEN OTHERS THEN + dbms_output.put_line('ERR:An error occurred with info :'|| + TO_CHAR(SQLCODE)||' '||SQLERRM); + END; +EXCEPTION + WHEN VALUE_ERROR THEN + /*......Handle the error */ + dbms_output.put_line('Value error occurred'); + WHEN OTHERS THEN + dbms_output.put_line('ERR:An error occurred with info :'|| + TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- A complete example using RAISE_APPLICATION_ERROR +CREATE OR REPLACE PROCEDURE org_proc + (p_flag_in VARCHAR2, + p_hrc_code NUMBER, + p_org_id NUMBER, + p_org_short_name VARCHAR2, + p_org_long_name VARCHAR2) +IS + v_error_code NUMBER; +BEGIN + IF (p_flag_in ='I')THEN + BEGIN + INSERT INTO org_tab VALUES + (p_hrc_code,p_org_id,p_org_short_name,p_org_long_name); + EXCEPTION WHEN OTHERS THEN + v_error_code :=SQLCODE; + IF v_error_code =-1 THEN + RAISE_APPLICATION_ERROR(-20000,'Organization '|| + TO_CHAR(p_org_id)|| + ' already exists. Cannot create a duplicate with the same id.'); + ELSIF v_error_code =-2291 THEN + RAISE_APPLICATION_ERROR(-20001,'Invalid Hierarchy Code '|| + TO_CHAR(p_hrc_code)|| + ' specified. Cannot create organization.'); + END IF; + END; + ELSIF (p_flag_in ='C')THEN + BEGIN + UPDATE org_tab + set org_short_name =p_org_short_name, + org_long_name =p_org_long_name + WHERE hrc_code =p_hrc_code + AND org_id =p_org_id; + IF SQL%NOTFOUND THEN + RAISE_APPLICATION_ERROR(-20002,'Organization '|| + TO_CHAR(p_org_id)|| + ' does not exist. Cannot change info for the same.'); + END IF; + END; + ELSIF (p_flag_in ='D')THEN + BEGIN + DELETE org_tab + WHERE hrc_code =p_hrc_code + AND org_id =p_org_id; + IF SQL%NOTFOUND THEN + RAISE_APPLICATION_ERROR(-20003,'Organization '|| + TO_CHAR(p_org_id)|| + ' does not exist. Cannot delete info for the same.'); + END IF; + EXCEPTION WHEN OTHERS THEN + v_error_code :=SQLCODE; + IF v_error_code =-2292 THEN + RAISE_APPLICATION_ERROR(-20004,'Organization '|| + TO_CHAR(p_org_id)|| + ' site details defined for it. Cannot perform delete operation.'); + END IF; + END; + END IF; +END; +/ + +-- Propogating a Server-side Customized Error Number and Error Message to +-- client program using a WHEN OTHERS handler +DECLARE + v_hrc_code NUMBER := 6; + v_org_id NUMBER := 1011; + v_org_short_name VARCHAR2(30):= 'Office of Mgr.ABC Inc.'; + v_org_long_name VARCHAR2(60):= 'Office of Mgr.ABC Inc.'; +BEGIN + org_proc('I',v_hrc_code,v_org_id,v_org_short_name,v_org_long_name); +EXCEPTION WHEN OTHERS THEN + DBMS_OUTPUT.PUT_LINE(TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- Propogating a Server-side Customized Error Number and Error Message to +-- client program using PRAGMA EXCEPTION_INIT +DECLARE + v_hrc_code NUMBER := 6; + v_org_id NUMBER := 1010; + v_org_short_name VARCHAR2(30):= 'Office of Mgr.ABC Inc.'; + v_org_long_name VARCHAR2(60):= 'Office of Mgr.ABC Inc.'; + excep1 EXCEPTION; + PRAGMA EXCEPTION_INIT(excep1,-20000); + excep2 EXCEPTION; + PRAGMA EXCEPTION_INIT(excep2,-20001); +BEGIN + org_proc('I',v_hrc_code,v_org_id,v_org_short_name,v_org_long_name); +EXCEPTION + WHEN excep1 or excep2 THEN + DBMS_OUTPUT.PUT_LINE(SQLERRM); + WHEN OTHERS THEN + DBMS_OUTPUT.PUT_LINE(TO_CHAR(SQLCODE)||SQLERRM); +END; +/ diff --git a/Chapter05/Chapter05.txt b/Chapter05/Chapter05.txt new file mode 100644 index 0000000..48a3e29 --- /dev/null +++ b/Chapter05/Chapter05.txt @@ -0,0 +1,847 @@ +-- Show_line procedure +CREATE OR REPLACE PROCEDURE show_line + (ip_line_length IN NUMBER, + ip_separator IN VARCHAR2) +IS + actual_line VARCHAR2(150); +BEGIN + FOR idx in 1..ip_line_length LOOP + actual_line :=actual_line ||ip_separator; + END LOOP; + DBMS_OUTPUT.PUT_LINE(actual_line); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); +END; +/ + +-- F_line function +CREATE OR REPLACE FUNCTION f_line + (ip_line_length IN NUMBER, + ip_separator IN VARCHAR2) +RETURN VARCHAR2 +IS + actual_line VARCHAR2(150); +BEGIN + FOR idx in 1..ip_line_length LOOP + actual_line :=actual_line ||ip_separator; + END LOOP; + RETURN (actual_line); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); + RETURN (null); +END; +/ + +-- Specifying procedure or function parameters +-- Positional notation +DECLARE + v_length NUMBER :=50; + v_separator VARCHAR2(1):='='; +BEGIN + show_line(v_length,v_separator); +END; +/ +-- Named notation +DECLARE + v_length NUMBER :=50; + v_separator VARCHAR2(1):='='; +BEGIN + show_line(ip_line_length=>v_length,ip_separator=>v_separator); +END; +/ +-- Mixed notation +DECLARE + v_length NUMBER :=50; + v_separator VARCHAR2(1):='='; +BEGIN + show_line(v_length,ip_separator=>v_separator); +END; +/ + +-- Procedure show_line2 +CREATE OR REPLACE PROCEDURE show_line2 + (ip_line_length IN NUMBER, + ip_separator IN VARCHAR2, + op_line OUT VARCHAR2) +IS + actual_line VARCHAR2(150); +BEGIN + FOR idx in 1..ip_line_length LOOP + actual_line :=actual_line ||ip_separator; + END LOOP; + op_line :=actual_line; +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); + op_line :=null; +END; +/ +-- Calling show_line2 +DECLARE + v_length NUMBER :=50; + v_separator VARCHAR2(1):='='; + v_line VARCHAR2(150); +BEGIN + show_line2(v_length,v_separator,v_line); + dbms_output.put_line(v_line); +END; +/ + +-- Show_line procedure with a default value for one parameter +CREATE OR REPLACE PROCEDURE show_line + (ip_line_length IN NUMBER, + ip_separator IN VARCHAR2 DEFAULT '=') +IS + actual_line VARCHAR2(150); +BEGIN + FOR idx in 1..ip_line_length LOOP + actual_line :=actual_line ||ip_separator; + END LOOP; + DBMS_OUTPUT.PUT_LINE(actual_line); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); +END; +/ + +-- Show_line procedure with a default value for both parameters +CREATE OR REPLACE PROCEDURE show_line + (ip_line_length IN NUMBER DEFAULT 50, + ip_separator IN VARCHAR2 DEFAULT '=') +IS + actual_line VARCHAR2(150); +BEGIN + FOR idx in 1..ip_line_length LOOP + actual_line :=actual_line ||ip_separator; + END LOOP; + DBMS_OUTPUT.PUT_LINE(actual_line); +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(SQLERRM); +END; +/ + +-- Package orgMaster +CREATE OR REPLACE PACKAGE orgMaster +IS + max_sites_for_an_org NUMBER; + TYPE rc IS REF CURSOR; + + PROCEDURE createOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); + + PROCEDURE updateOrg (ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); + + PROCEDURE removeOrg (ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); + + FUNCTION getOrgInfo (ip_org_id NUMBER) RETURN rc; + + FUNCTION getAllOrgs (ip_hrc_code NUMBER) RETURN rc; + + PROCEDURE assignSiteToOrg (ip_org_id NUMBER, + ip_site_no NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); + +END orgMaster; +/ +CREATE OR REPLACE PACKAGE BODY orgMaster +IS + --Procedure to remove rows from org_site_tab table for a given org_id + --This is necessary before deleting rows from org_tab. + --This procedure is called from removeOrg procedure + PROCEDURE removeOrgSites(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + DELETE org_site_tab WHERE org_id = ip_org_id; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END removeOrgSites; + + --Procedure to create a new Org record in org_tab + PROCEDURE createOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + INSERT INTO org_tab VALUES + (ip_hrc_code,ip_org_id,ip_org_short_name,ip_org_long_name); + op_retcd :=0; + EXCEPTION WHEN DUP_VAL_ON_INDEX THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'already exists.'; + WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END createOrg; + + --Procedure to update the short and long names of an Org in org_tab + --based on input org_id + PROCEDURE updateOrg(ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + UPDATE org_tab + SET org_short_name =ip_org_short_name, + org_long_name =ip_org_long_name + WHERE org_id =ip_org_id; + IF (SQL%NOTFOUND) THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'; + RETURN; + END IF; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END updateOrg; + + --Procedure to delete a record in org_tab + PROCEDURE removeOrg(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + removeOrgSites(ip_org_id,op_retcd,op_err_msg); + IF (op_retcd <>0) then + RETURN; + END IF; + DELETE org_tab WHERE org_id = ip_org_id; + IF (SQL%NOTFOUND) THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'; + RETURN; + END IF; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END removeOrg; + + --Function to return a row in org_tab for a given org_id. + --It returns a resultset of type REF CURSOR defined in the package specification + FUNCTION getOrgInfo(ip_org_id NUMBER) RETURN rc + IS + v_rc rc; + BEGIN + OPEN v_rc FOR SELECT * FROM org_tab WHERE org_id = ip_org_id; + RETURN (v_rc); + EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20001,SQLERRM); + END getOrgInfo; + + --Function to return all rows in org_tab. + --It returns a resultset of type REF CURSOR defined in the package specification + FUNCTION getAllOrgs(ip_hrc_code NUMBER) RETURN rc + IS + v_rc rc; + BEGIN + OPEN v_rc FOR SELECT * FROM org_tab WHERE hrc_code = ip_hrc_code; + RETURN (v_rc); + EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20002,SQLERRM); + END getAllOrgs; + + --Procedure to insert a row into org_site_tab based on + --input org_id and site_no + PROCEDURE assignSiteToOrg(ip_org_id NUMBER, + ip_site_no NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + v_num NUMBER; + BEGIN + BEGIN + SELECT 1 + INTO v_num + FROM org_site_tab + WHERE org_id = ip_org_id + AND site_no = ip_site_no; + IF (v_num =1) THEN + op_retcd :=0; + RETURN; + END IF; + EXCEPTION WHEN NO_DATA_FOUND THEN + INSERT INTO org_site_tab VALUES (ip_org_id,ip_site_no); + END; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END assignSiteToOrg; + + --This is the initialization section that is executed + --the first time a package sub-program is invoked + --or a packaged variable is referenced + BEGIN + max_sites_for_an_org :=4; +END orgMaster; +/ + +-- Subprograms returning resultsets, function getAllHierarchies +CREATE OR REPLACE FUNCTION getAllHierarchies +RETURN SYS_REFCURSOR +IS + v_rc SYS_REFCURSOR; +BEGIN + OPEN v_rc FOR SELECT * FROM hrc_tab; + RETURN (v_rc); +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20002,SQLERRM); +END; +/ + +-- Calling the above function +DECLARE + v_rc SYS_REFCURSOR; + hrc_rec hrc_tab%ROWTYPE; +BEGIN + v_rc :=getAllHierarchies; + LOOP + FETCH v_rc INTO hrc_rec; + EXIT WHEN v_rc%NOTFOUND; + dbms_output.put_line(TO_CHAR(hrc_rec.hrc_code)||' '||hrc_rec.hrc_descr); + END LOOP; +EXCEPTION WHEN OTHERS THEN + dbms_output.put_line(TO_CHAR(SQLCODE)||' '||SQLERRM); +END; +/ + +-- Using stored functions in SQL statements, function f_get_formatted_org_name +CREATE OR REPLACE FUNCTION f_get_formatted_org_name + (ip_hrc_code NUMBER, + ip_org_id NUMBER) +RETURN VARCHAR2 +IS + v_name VARCHAR2(120); +BEGIN + SELECT 'Org Name: (Short) '||org_short_name||' (Long) '||org_long_name + INTO v_name + FROM org_tab + WHERE hrc_code = ip_hrc_code + AND org_id = ip_org_id; + RETURN (v_name); +END f_get_formatted_org_name; +/ +-- Calling the above function from SQL +SELECT f_get_formatted_org_name(hrc_code,org_id) "Formatted Org Name" +FROM org_tab +ORDER BY hrc_code,org_id; + +-- Package rfPkg +CREATE OR REPLACE PACKAGE rfPkg +IS + FUNCTION f_get_formatted_org_name + (ip_hrc_code NUMBER, + ip_org_id NUMBER) + RETURN VARCHAR2; + PRAGMA RESTRICT_REFERENCES(f_get_formatted_org_name,WNDS,WNPS); +END rfPkg; +/ +CREATE OR REPLACE PACKAGE BODY rfPkg +IS + FUNCTION f_get_formatted_org_name + (ip_hrc_code NUMBER, + ip_org_id NUMBER) + RETURN VARCHAR2 + IS + v_name VARCHAR2(120); + BEGIN + SELECT 'Org Name: (Short) '||org_short_name||' (Long) '||org_long_name + INTO v_name + FROM org_tab + WHERE hrc_code = ip_hrc_code + AND org_id = ip_org_id; + RETURN (v_name); + END f_get_formatted_org_name; +END rfPkg; +/ + +-- Calling the above packaged function from SQL +SELECT rfPkg.f_get_formatted_org_name(hrc_code,org_id) "Formatted Org Name" +FROM org_tab +ORDER BY hrc_code,org_id; + +-- Package rfPkg2 +CREATE OR REPLACE PACKAGE rfPkg2 +IS + FUNCTION f_get_formatted_org_name + (ip_hrc_code NUMBER, + ip_org_id NUMBER) + RETURN VARCHAR2; + PRAGMA RESTRICT_REFERENCES(f_get_formatted_org_name,WNDS,WNPS); +END rfPkg2; +/ +CREATE OR REPLACE PACKAGE BODY rfPkg2 +IS + FUNCTION f_get_formatted_org_name + (ip_hrc_code NUMBER, + ip_org_id NUMBER) + RETURN VARCHAR2 + IS + v_name VARCHAR2(120); + v_hrc_descr VARCHAR2(20); + v_org_short_name VARCHAR2(30); + v_org_long_name VARCHAR2(60); + BEGIN + SELECT 'Org Name: (Short) '||org_short_name||' (Long) '||org_long_name + INTO v_name + FROM org_tab + WHERE hrc_code = ip_hrc_code + AND org_id = ip_org_id; + SELECT hrc_descr + INTO v_hrc_descr + FROM hrc_tab + WHERE hrc_code = ip_hrc_code; + SELECT org_short_name,org_long_name + INTO v_org_short_name,v_org_long_name + FROM org_tab + WHERE hrc_code = ip_hrc_code + AND org_id = ip_org_id; + INSERT INTO sec_hrc_org_tab VALUES + (ip_hrc_code,v_hrc_descr,ip_org_id, + v_org_short_name,v_org_long_name); + RETURN (v_name); + END f_get_formatted_org_name; +END rfPkg2; +/ + +-- Specifying the TRUST keyword +-- Package dirPkg +CREATE OR REPLACE PACKAGE dirPkg IS + FUNCTION FileType(ip_file_name VARCHAR2) + RETURN VARCHAR2 + IS LANGUAGE JAVA + NAME 'dirClass.fileType(java.lang.String)return java.lang.String'; + PRAGMA RESTRICT_REFERENCES(FileType,WNDS,TRUST); + + FUNCTION displayFileType(ip_file_name VARCHAR2) + RETURN VARCHAR2; + PRAGMA RESTRICT_REFERENCES(displayFileType,WNDS); +END dirPkg; +/ +CREATE OR REPLACE PACKAGE BODY dirPkg IS + FUNCTION displayFileType(ip_file_name VARCHAR2) + RETURN VARCHAR2 + IS + v_descr VARCHAR2(100); + BEGIN + v_descr :=ip_file_name||' '||'is a '||FileType(ip_file_name); + RETURN (v_descr); + END displayFileType; +END dirPkg; +/ + +--Package dirPkg2 +CREATE OR REPLACE PACKAGE dirPkg2 IS + FUNCTION FileType(ip_file_name VARCHAR2) + RETURN VARCHAR2 + IS LANGUAGE JAVA + NAME 'dirClass.fileType(java.lang.String)return java.lang.String'; + + FUNCTION displayFileType(ip_file_name VARCHAR2) + RETURN VARCHAR2; + PRAGMA RESTRICT_REFERENCES(displayFileType,WNDS,TRUST); +END dirPkg2; +/ +CREATE OR REPLACE PACKAGE BODY dirPkg2 IS + FUNCTION displayFileType(ip_file_name VARCHAR2) + RETURN VARCHAR2 + IS + v_descr VARCHAR2(100); + BEGIN + v_descr :=ip_file_name||' '||'is a '||FileType(ip_file_name); + RETURN (v_descr); + END displayFileType; +END dirPkg2; +/ + +-- Parameter passing by reference +-- Procedure p_nocopy +CREATE OR REPLACE PROCEDURE p_nocopy + (ip_1 IN NUMBER, + op_2 OUT NOCOPY VARCHAR2) +IS +BEGIN + NULL; +END; +/ + +-- Performance improvement of NOCOPY +CREATE OR REPLACE PACKAGE NoCopyPkg +is + type arr is varray(100000)of hrc_tab%ROWTYPE; + procedure p1(ip1 IN OUT arr); + procedure p2(ip1 IN OUT NOCOPY arr); + FUNCTION get_time RETURN NUMBER; +END NoCopyPkg; +/ +CREATE OR REPLACE PACKAGE BODY NoCopyPkg +is + PROCEDURE p1(ip1 IN OUT arr) + IS + BEGIN + NULL; + END; + PROCEDURE p2(ip1 IN OUT NOCOPY arr) + IS + BEGIN + NULL; + END; + FUNCTION get_time RETURN NUMBER + IS + BEGIN + RETURN (dbms_utility.get_time); + EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20010,SQLERRM); + END get_time; +END NoCopyPkg; +/ +declare + arr1 NoCopyPkg.arr :=NoCopyPkg.arr(null); + cur_t1 number; + cur_t2 number; + cur_t3 number; +begin + select * into arr1(1)from hrc_tab where hrc_code =1; + /*Create 99999 new elements in the variable array + and populate each with the value in the 1st element */ + arr1.extend(99999,1); + cur_t1 :=NoCopyPkg.get_time; + NoCopyPkg.p1(arr1); + cur_t2 :=NoCopyPkg.get_time; + NoCopyPkg.p2(arr1); + cur_t3 :=NoCopyPkg.get_time; + dbms_output.put_line('Without NOCOPY '||to_char((cur_t2-cur_t1)/100)); + dbms_output.put_line('With NOCOPY '||to_char((cur_t3-cur_t2)/100)); +end; +/ + +-- Invoker Rights Model +connect system/manager; +create user region1 identified by region1; +grant connect,resource to region1; +create user region2 identified by region2; +grant connect,resource to region2; + +Create or replace Procedure create_dyn_table + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +is + cur_id INTEGER; + ret_code INTEGER; + dyn_string VARCHAR2(1000); + dyn_Table_name VARCHAR2(21); +Begin + dyn_table_name :='ORDERS_FOR_'||i_region_name; + dyn_string :='CREATE TABLE '||dyn_table_name|| + '(order_id NUMBER(10)PRIMARY KEY, + order_date DATE NOT NULL, + total_qty NUMBER, + total_price NUMBER(15,2))'; + cur_id :=DBMS_SQL.OPEN_CURSOR; + DBMS_SQL.PARSE(cur_id,dyn_string,DBMS_SQL.V7); + ret_code :=DBMS_SQL.EXECUTE(cur_id); + DBMS_SQL.CLOSE_CURSOR(cur_id); + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR:Creating table '||dyn_table_name ||'-'||SQLERRM; +End; +/ + +-- Overloading Packaged procedures and functions +-- Package orgMaster2 +CREATE OR REPLACE PACKAGE orgMaster2 +IS +max_sites_for_an_org NUMBER; +TYPE rc IS REF CURSOR; +PROCEDURE createOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); +PROCEDURE updateOrg(ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); +PROCEDURE removeOrg(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); +FUNCTION getOrgDetails(ip_hrc_code NUMBER) RETURN rc; +FUNCTION getOrgDetails(ip_hrc_code NUMBER,ip_org_id NUMBER) RETURN rc; +PROCEDURE assignSiteToOrg(ip_org_id NUMBER, + ip_site_no NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2); +END orgMaster2; +/ +CREATE OR REPLACE PACKAGE BODY orgMaster2 +IS + --Procedure to delete records from the org_site_tab table + --before deleting from org_table.This procedure is called + --from the removeOrg procedure + PROCEDURE removeOrgSites(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + DELETE org_site_tab WHERE org_id =ip_org_id; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END removeOrgSites; + + --Procedure to create a record in the org_tab table + PROCEDURE createOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + INSERT INTO org_tab VALUES + (ip_hrc_code,ip_org_id,ip_org_short_name,ip_org_long_name); + op_retcd :=0; + EXCEPTION WHEN DUP_VAL_ON_INDEX THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'already exists.'; + WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END createOrg; + + --Procedure to update the long and short names for a + --given org_id in the org_tab table + PROCEDURE updateOrg(ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + UPDATE org_tab + SET org_short_name =ip_org_short_name, + org_long_name =ip_org_long_name + WHERE org_id =ip_org_id; + IF (SQL%NOTFOUND) THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'; + RETURN; + END IF; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END updateOrg; + + --Procedure to remove a record from the org_tab table + PROCEDURE removeOrg(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + removeOrgSites(ip_org_id,op_retcd,op_err_msg); + IF (op_retcd <>0) then + RETURN; + END IF; + DELETE org_tab WHERE org_id =ip_org_id; + IF (SQL%NOTFOUND) THEN + op_retcd :=-1; + op_err_msg :='Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'; + RETURN; + END IF; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END removeOrg; + + --Over-loaded function that returns a row from the org_tab table + --based on input hrc_code and org_id + FUNCTION getOrgDetails(ip_hrc_code NUMBER,ip_org_id NUMBER)RETURN rc + IS + v_rc rc; + BEGIN + OPEN v_rc FOR SELECT * FROM org_tab + WHERE hrc_code =ip_hrc_code + AND org_id =ip_org_id; + RETURN (v_rc); + EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20001,SQLERRM); + END getOrgDetails; + + --Over-loaded function that returns all row from the org_tab table + --for an input hrc_code.This function has the same name as the function + --above,but the number of parameters is different in each case. + FUNCTION getOrgDetails(ip_hrc_code NUMBER)RETURN rc + IS + v_rc rc; + BEGIN + OPEN v_rc FOR SELECT * FROM org_tab WHERE hrc_code =ip_hrc_code; + RETURN (v_rc); + EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20002,SQLERRM); + END getOrgDetails; + + --Procedure to create a row in the org_site_tab table + --based on input org_id and site_no + PROCEDURE assignSiteToOrg(ip_org_id NUMBER, + ip_site_no NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + v_num NUMBER; + BEGIN + BEGIN + SELECT 1 + INTO v_num + FROM org_site_tab + WHERE org_id =ip_org_id + AND site_no =ip_site_no; + IF (v_num =1) THEN + op_retcd :=0; + RETURN; + END IF; + EXCEPTION WHEN NO_DATA_FOUND THEN + INSERT INTO org_site_tab VALUES (ip_org_id,ip_site_no); + END; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END assignSiteToOrg; + + --Initialization section for the package + BEGIN + max_sites_for_an_org :=4; +END orgMaster2; +/ +DECLARE + v_rc orgMaster2.rc; + org_rec org_tab%ROWTYPE; +BEGIN + DBMS_OUTPUT.PUT_LINE('Org Details for Org 1001'); + DBMS_OUTPUT.PUT_LINE('------------------'); + v_rc :=orgMaster2.getOrgDetails(1,1001); + FETCH v_rc INTO org_rec; + DBMS_OUTPUT.PUT_LINE(TO_CHAR(org_rec.hrc_code)||' '|| + TO_CHAR(org_rec.org_id)||''|| + org_rec.org_short_name||' '|| + org_rec.org_long_name); + DBMS_OUTPUT.PUT_LINE('Org Details for Hierarchy 1'); + DBMS_OUTPUT.PUT_LINE('------------------'); + v_rc :=orgMaster2.getOrgDetails(1); + LOOP + FETCH v_rc INTO org_rec; + EXIT WHEN v_rc%NOTFOUND; + DBMS_OUTPUT.PUT_LINE(TO_CHAR(org_rec.hrc_code)||' '|| + TO_CHAR(org_rec.org_id)||' '|| + org_rec.org_short_name||' '|| + org_rec.org_long_name); + END LOOP; + CLOSE v_rc; +END; +/ + +-- Serially Reusable Packages +-- Package srPkg1 +CREATE OR REPLACE PACKAGE srPkg1 +IS + PRAGMA SERIALLY_REUSABLE; + num_var NUMBER; + char_var VARCHAR2(20); + PROCEDURE initialize; + FUNCTION display_num RETURN NUMBER; + FUNCTION display_char RETURN VARCHAR2; +END srPkg1; +/ +CREATE OR REPLACE PACKAGE BODY srPkg1 +IS + PRAGMA SERIALLY_REUSABLE; + PROCEDURE initialize + IS + BEGIN + num_var :=100; + char_var :='Test String1'; + END; + FUNCTION display_num RETURN NUMBER + IS + BEGIN + RETURN (num_var); + END; + FUNCTION display_char RETURN VARCHAR2 + IS + BEGIN + RETURN (char_var); + END; +END srPkg1; +/ +DECLARE + v_num NUMBER; + v_char VARCHAR2(20); +BEGIN + srPkg1.initialize; + v_num :=srPkg1.display_num; + v_char :=srPkg1.display_char; + dbms_output.put_line(TO_CHAR(v_num)||' '||v_char); +END; +/ +CREATE OR REPLACE PACKAGE srPkg2 +IS + PRAGMA SERIALLY_REUSABLE; + CURSOR csr_sites IS + SELECT * from site_tab ORDER BY site_no; + PROCEDURE displaySites; +END srPkg2; +/ +CREATE OR REPLACE PACKAGE BODY srPkg2 +IS + PRAGMA SERIALLY_REUSABLE; + PROCEDURE displaySites + IS + site_rec site_tab%ROWTYPE; + BEGIN + OPEN csr_sites; + FETCH csr_sites INTO site_rec; + dbms_output.put_line(TO_CHAR(site_rec.site_no)||' '|| + site_rec.site_descr); + FETCH csr_sites INTO site_rec; + dbms_output.put_line(TO_CHAR(site_rec.site_no)||' '|| + site_rec.site_descr); + END displaySites; +END srPkg2; +/ +BEGIN + srPkg2.displaySites; +END; +/ diff --git a/Chapter05/authid.sql b/Chapter05/authid.sql new file mode 100644 index 0000000..cf081e6 --- /dev/null +++ b/Chapter05/authid.sql @@ -0,0 +1,51 @@ +/*File name authid.sql */ +connect plsql9i/plsql9i; + +Create or replace Procedure create_dyn_table + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +is + cur_id INTEGER; + ret_code INTEGER; + dyn_string VARCHAR2(1000); + dyn_Table_name VARCHAR2(21); +Begin + dyn_table_name :=‘ORDERS_FOR_’||i_region_name; + dyn_string :=‘CREATE TABLE ‘||dyn_table_name|| + ‘(order_id NUMBER(10)PRIMARY KEY, + order_date DATE NOT NULL, + total_qty NUMBER, + total_price NUMBER(15,2))’; + cur_id :=DBMS_SQL.OPEN_CURSOR; + DBMS_SQL.PARSE(cur_id,dyn_string,DBMS_SQL.V7); + ret_code :=DBMS_SQL.EXECUTE(cur_id); + DBMS_SQL.CLOSE_CURSOR(cur_id); + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :=‘ERR:Creating table ‘||dyn_table_name ||’-‘||SQLERRM; +End; +/ +grant execute on create_dyn_table to public; +connect region1/region1; +create synonym create_dyn_table for plsql9i.create_dyn_table; +declare + retcd NUMBER; + errmsg VARCHAR2(100); +begin + create_dyn_table(‘REGION1’,retcd,errmsg); +end; +/ +select table_name from user_tables where table_name like ‘%REGION1’; +connect region2/region2; +create synonym create_dyn_table for plsql9i.create_dyn_table; +declare + retcd NUMBER; + errmsg VARCHAR2(100); +begin + create_dyn_table(‘REGION2’,retcd,errmsg); +end; +/ +select table_name from user_tables where table_name like ‘%REGION2’; diff --git a/Chapter06/Chapter06.txt b/Chapter06/Chapter06.txt new file mode 100644 index 0000000..69b792c --- /dev/null +++ b/Chapter06/Chapter06.txt @@ -0,0 +1,195 @@ +-- Trigger ai_org_trig +CREATE OR REPLACE TRIGGER ai_org_trig +AFTER INSERT ON org_tab +FOR EACH ROW +BEGIN + UPDATE sec_hrc_audit + SET num_rows =num_rows+1 + WHERE hrc_code =:NEW.hrc_code; + IF (SQL%NOTFOUND) THEN + INSERT INTO sec_hrc_audit VALUES (:NEW.hrc_code,1); + END IF; +END; +/ + +-- Trigger ai_org_trig_statement +CREATE OR REPLACE TRIGGER ai_org_trig_statement +AFTER INSERT ON org_tab +BEGIN + FOR idx IN (SELECT hrc_code,COUNT(*)cnt + FROM org_tab + GROUP BY hrc_code) LOOP + UPDATE sec_hrc_audit + SET num_rows =idx.cnt + WHERE hrc_code =idx.hrc_code; + IF (SQL%NOTFOUND) THEN + INSERT INTO sec_hrc_audit VALUES (idx.hrc_code,idx.cnt); + END IF; + END LOOP; +END; +/ +-- Trigger ai_org_trig with a REFERENCING clause +CREATE OR REPLACE TRIGGER ai_org_trig +AFTER INSERT ON org_tab +REFERENCING NEW AS new_org +FOR EACH ROW +BEGIN + UPDATE sec_hrc_audit + SET num_rows =num_rows+1 + WHERE hrc_code =:new_org.hrc_code; + IF (SQL%NOTFOUND) THEN + INSERT INTO sec_hrc_audit VALUES (:new_org.hrc_code,1); + END IF; +END; +/ +-- Trigger ai_org_trig with REFERENCING and WHEN clauses +CREATE OR REPLACE TRIGGER ai_org_trig +AFTER INSERT ON org_tab +REFERENCING NEW AS new_org +FOR EACH ROW +WHEN (new_org.hrc_code <>1) +BEGIN + UPDATE sec_hrc_audit + SET num_rows =num_rows+1 + WHERE hrc_code =:new_org.hrc_code; + IF (SQL%NOTFOUND) THEN + INSERT INTO sec_hrc_audit VALUES (:new_org.hrc_code,1); + END IF; +END; +/ + +-- Trigger ai_org_trig with multiple triggering events +CREATE OR REPLACE TRIGGER ai_org_trig +AFTER INSERT OR DELETE ON org_tab +FOR EACH ROW +BEGIN + IF INSERTING THEN + UPDATE sec_hrc_audit + SET num_rows =num_rows+1 + WHERE hrc_code =:NEW.hrc_code; + IF (SQL%NOTFOUND) THEN + INSERT INTO sec_hrc_audit VALUES (:NEW.hrc_code,1); + END IF; + ELSIF DELETING THEN + UPDATE sec_hrc_audit + SET num_rows =num_rows-1 + WHERE hrc_code =:OLD.hrc_code; + END IF; +END; +/ + +-- INSTEAD-OF triggers +CREATE VIEW hrc_org_site +AS + SELECT h.hrc_code,hrc_descr, + o.org_id,org_short_name,org_long_name, + os.site_no,site_descr + FROM org_site_tab os,org_tab o,hrc_tab h,site_tab s + WHERE os.org_id =o.org_id + AND o.hrc_code =h.hrc_code + AND os.site_no =s.site_no; + +CREATE OR REPLACE TRIGGER hrc_org_site_trig +INSTEAD OF INSERT OR UPDATE OR DELETE on hrc_org_site +FOR EACH ROW +BEGIN + IF INSERTING THEN + INSERT INTO hrc_tab VALUES (:NEW.hrc_code,:NEW.hrc_descr); + INSERT INTO org_tab VALUES (:NEW.hrc_code,:NEW.org_id, + :NEW.org_short_name, :NEW.org_long_name); + INSERT INTO org_site_tab VALUES (:NEW.org_id,:NEW.site_no); + ELSIF UPDATING THEN + IF (:NEW.hrc_descr !=:OLD.hrc_descr) THEN + UPDATE hrc_tab + SET hrc_descr =:NEW.hrc_descr + WHERE hrc_code =:OLD.hrc_code; + END IF; + IF (:NEW.org_short_name !=:OLD.org_short_name) THEN + UPDATE org_tab + SET org_short_name =:NEW.org_short_name, + org_long_name =:NEW.org_long_name + WHERE hrc_code =:OLD.hrc_code + AND org_id =:OLD.org_id; + ELSIF (:NEW.org_long_name !=:OLD.org_long_name) THEN + UPDATE org_tab + SET org_long_name =:NEW.org_long_name + WHERE hrc_code =:OLD.hrc_code + AND org_id =:OLD.org_id; + END IF; + UPDATE org_site_tab + SET site_no =:NEW.site_no + WHERE org_id =:NEW.org_id; + IF (SQL%NOTFOUND) THEN + INSERT INTO org_site_tab VALUES (:NEW.org_id,:NEW.org_id); + END IF; + ELSIF DELETING THEN + DELETE org_site_tab WHERE org_id =:OLD.org_id; + DELETE org_level WHERE org_id =:OLD.org_id; + DELETE org_tab WHERE hrc_code =:OLD.hrc_code + AND org_id =:OLD.org_id; + END IF; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20010,'ERR occurred in trigger hrc_org_site_trig '|| + SQLERRM); +END; +/ + +-- Testing of the above trigger +-- INSERT operation +SELECT * FROM hrc_tab WHERE hrc_code =11; +SELECT * FROM org_tab WHERE org_id =1012; +SELECT * FROM org_site_tab WHERE org_id =1012; +INSERT INTO hrc_org_site VALUES (11,'ANALYST',1012,'Office of Analyst', +2 'Office of Analyst',4,null); +SELECT * FROM hrc_tab WHERE hrc_code =11; +SELECT * FROM org_tab WHERE org_id =1012; +SELECT * FROM org_site_tab WHERE org_id =1012; + +-- UPDATE operation +UPDATE hrc_org_site SET org_short_name ='Office of Analyst ABC Inc.', + org_long_name ='Office of Analyst ABC Inc.',site_no =4 +WHERE hrc_code =11 +AND org_id =1012; +select * from hrc_tab where hrc_code =11; +select * from org_tab where org_id =1012; +select * from org_site_tab where org_id =1012; + +-- DELETE operation +DELETE hrc_org_site WHERE org_id =1012; +select * from hrc_tab where hrc_code =11; +select * from org_tab where org_id =1012; +select * from org_site_tab where org_id =1012; +select * from org_level where org_id =1012; + +-- New Database triggers +CREATE OR REPLACE TRIGGER On_Logon +AFTER LOGON +ON SCHEMA +BEGIN + DBMS_UTILITY.ANALYZE_SCHEMA(sys.login_user,'ESTIMATE'); +END; +/ +CREATE TABLE DDL_AUDIT +(object_name VARCHAR2(30)NOT NULL, + Object_type VARCHAR2(30)NOT NULL, + WHEN_CREATED DATE NOT NULL, + WHO_CREATED VARCHAR2(30)NOT NULL, + WHEN_UPDATED DATE, + WHO_UPDATED VARCHAR2(30)); + +CREATE OR REPLACE TRIGGER after_ddl_creation +AFTER CREATE ON SCHEMA +BEGIN + INSERT INTO ddl_audit VALUES + (SYS.DICTIONARY_OBJ_NAME,SYS.DICTIONARY_OBJ_TYPE,SYSDATE,USER,NULL,NULL); +END; +/ + +CREATE OR REPLACE PROCEDURE p_dummy +IS +BEGIN + NULL; +END; +/ + +SELECT * FROM ddl_audit; diff --git a/Chapter07/Chapter07.txt b/Chapter07/Chapter07.txt new file mode 100644 index 0000000..9547a25 --- /dev/null +++ b/Chapter07/Chapter07.txt @@ -0,0 +1,233 @@ +-- An example of code using native dynamic SQL +/*Native Dynamic SQL */ +DECLARE + dyn_tab_name VARCHAR2(30):='temp'; + dyn_string VARCHAR2(150); +BEGIN + dyn_string :='create table '||dyn_tab_name||'(col1 NUMBER NOT NULL)'; + EXECUTE IMMEDIATE dyn_string; +END; +/ + +-- An example of the same using DBMS_SQL +drop table temp; +--DBMS_SQL +DECLARE + dyn_tab_name VARCHAR2(30):='temp'; + dyn_string VARCHAR2(150); + c INTEGER; + ret_code INTEGER; +BEGIN + dyn_string :='create table '||dyn_tab_name|| + '(col1 NUMBER NOT NULL)'; + c :=DBMS_SQL.OPEN_CURSOR; + DBMS_SQL.PARSE(c,dyn_string,DBMS_SQL.V7); + ret_code :=DBMS_SQL.EXECUTE(c); + DBMS_SQL.CLOSE_CURSOR(c); +END; +/ +-- Dynamic DDL +-- Procedure create_dyn_table +Create or replace Procedure create_dyn_table + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + Dyn_string VARCHAR2(1000); + Dyn_Table_name VARCHAR2(30); +Begin + Dyn_table_name :='ORDERS_FOR_'||replace(trim(i_region_name),'','_'); + Dyn_string :='CREATE TABLE '||dyn_table_name|| + '(order_id NUMBER(10)PRIMARY KEY, + order_date DATE NOT NULL, + total_qty NUMBER, + total_price NUMBER(15,2), + supp_id NUMBER(6)REFERENCES supplier_tab(supp_id))'; + EXECUTE IMMEDIATE dyn_string ; + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR:Creating table '||dyn_table_name ||'-'||SQLERRM; +End; +/ + +-- Procedure create_dyn_table2 +Create or replace Procedure create_dyn_table2 + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + Dyn_string VARCHAR2(1000); + Dyn_Table_name VARCHAR2(30); +Begin + Dyn_table_name :='ORDER_ITEMS_FOR_'||replace(trim(i_region_name),'','_'); + Dyn_string :='CREATE TABLE '||dyn_table_name|| + '(order_id NUMBER(10)NOT NULL, + item_id VARCHAR2(10)NOT NULL, + unit_price NUMBER(11,2)NOT NULL, + quantity NUMBER)'; + EXECUTE IMMEDIATE dyn_string ; + dyn_string := + 'alter table ORDER_ITEMS_FOR_'||i_region_name||'add constraint '|| + 'fk_oifor '||i_region_name||'foreign key (order_id)references '|| + 'orders_for_'||i_region_name||'(order_id)'; + EXECUTE IMMEDIATE dyn_string ; + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR:Creating/Altering table '||dyn_table_name ||'-'||SQLERRM; +End; +/ + +-- Procedure create_dyn_for_all +Create or replace Procedure create_dyn_for_all + (retcd OUT NUMBER,errmsg OUT VARCHAR2) +Authid current_user +Is + CURSOR csr_region IS + SELECT region_name + FROM region_tab; +BEGIN + FOR idx IN csr_region LOOP + create_dyn_table(idx.region_name,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + create_dyn_table2(idx.region_name,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ + +-- Executing create_dyn_for_all +DECLARE + Retcd NUMBER; + Errmsg VARCHAR2(32767); +BEGIN + Create_dyn_for_all(retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20102,errmsg); + END IF; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20103,SQLERRM); +END; +/ +select object_name,object_type from user_objects +where object_name like 'ORDER%FOR%'; + +-- Dynamic SELECTS +-- Single-row SELECTS +-- Procedure update_dyn_table +Create or replace Procedure update_dyn_table + (i_region_name VARCHAR2, + i_order_id NUMBER, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + Dyn_upd_string1 VARCHAR2(1000); + Dyn_query_string VARCHAR2(1000); + Dyn_Table_name1 VARCHAR2(30); + Dyn_Table_name2 VARCHAR2(30); + V_total_price NUMBER; + V_total_quantity NUMBER; +Begin + Dyn_table_name1 :='ORDER_ITEMS_FOR_'||replace(trim(i_region_name),'','_'); + Dyn_table_name2 :='ORDERS_FOR_'||i_region_name; + Dyn_query_string :='SELECT SUM(quantity),SUM(unit_price*quantity)FROM '|| + dyn_table_name1|| + 'WHERE order_id =:input_order_id'; + Dyn_upd_string1 :=' UPDATE '||dyn_table_name2|| + 'SET total_qty =:total_qty,total_price =:total_price WHERE '|| + 'order_id =:input_order_id'; + EXECUTE IMMEDIATE dyn_query_string INTO v_total_price,v_total_quantity + USING i_order_id; + EXECUTE IMMEDIATE dyn_upd_string1 + USING v_total_quantity,v_total_price,i_order_id; + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR: '||SQLERRM; +End; +/ + +-- Multi-row SELECTS +-- Procedure update_dyn_for_all_orders +Create or replace Procedure update_dyn_for_all_orders + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +Is + Dyn_table_name VARCHAR2(100); + Dyn_query_string VARCHAR2(1000); + Type csr_dyn IS REF CURSOR; + csr_dyn1 csr_dyn; + v_order_id NUMBER; +BEGIN + Dyn_table_name :='ORDER_ITEMS_FOR_'||replace(trim(i_region_name),'','_'); + Dyn_query_string :='SELECT order_id FROM '||dyn_table_name; + OPEN csr_dyn1 FOR dyn_query_string; + LOOP + FETCH csr_dyn1 INTO v_order_id; + EXIT WHEN csr_dyn1%NOTFOUND; + update_dyn_table(i_region_name,v_order_id,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ + +-- Procedure update_dyn_global +Create or replace Procedure update_dyn_global + (retcd OUT NUMBER, + errmsg OUT VARCHAR2) +Is + CURSOR csr_region IS + SELECT region_name FROM region_tab; +BEGIN + FOR idx IN csr_region LOOP + update_dyn_for_all_orders(idx.region_name,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ + +-- Dynamic PL/SQL +-- Procedure update_dyn_global2 +Create or replace Procedure update_dyn_global2 + (retcd OUT NUMBER, + errmsg OUT VARCHAR2) +Is + CURSOR csr_region IS + SELECT region_name FROM region_tab; + Dyn_proc_name VARCHAR2(100); + Dyn_plsql_string VARCHAR2(1000); +BEGIN + FOR idx IN csr_region LOOP + EXECUTE IMMEDIATE 'BEGIN update_dyn_'||replace(trim(idx.region_name),'','_')||'(:1,:2);END;' + USING OUT retcd,OUT errmsg; + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ diff --git a/Chapter08/Chapter08.txt b/Chapter08/Chapter08.txt new file mode 100644 index 0000000..7d4e0a2 --- /dev/null +++ b/Chapter08/Chapter08.txt @@ -0,0 +1,75 @@ +-- Procedure log_error +CREATE OR REPLACE PROCEDURE log_error + (p_order_id NUMBER, + p_error_code NUMBER, + p_error_text VARCHAR2) +IS + PRAGMA AUTONOMOUS_TRANSACTION; +BEGIN + INSERT INTO error_log VALUES + (p_order_id,p_error_code,p_error_text,USER,SYSDATE); + COMMIT; +END; +/ + +-- Procedure create_order +CREATE OR REPLACE PROCEDURE create_order(p_order_id NUMBER) +IS +BEGIN + INSERT INTO order_tab VALUES(p_order_id,SYSDATE,NULL,NULL,1001); + COMMIT; +EXCEPTION WHEN OTHERS THEN + log_error(p_order_id,SQLCODE,SQLERRM); + ROLLBACK; +END; +/ + +DECLARE + PRAGMA AUTONOMOUS_TRANSACTION; + FUNCTION dummy_log_error RETURN NUMBER; + v_num NUMBER(1):=0; + retcd NUMBER :=dummy_log_error; + FUNCTION dummy_log_error RETURN NUMBER + IS + BEGIN + INSERT INTO error_log VALUES (-99,-99,’Dummy Error!’,USER,SYSDATE); + RETURN (-99); + END; +BEGIN + INSERT INTO error_log VALUES (v_num,v_num,‘No Error!’,USER,SYSDATE); + COMMIT; +END; +/ + +-- Autonomous triggers +create or replace trigger bi_order_tab +before insert on order_tab for each row +declare + pragma autonomous_transaction; +begin + insert into order_tran_coming_in values (:NEW.order_id, + :NEW.order_date, + SYSDATE, + 'N'); + commit; +end; +/ +create or replace trigger ai_order_tab +after insert on order_tab for each row +declare + pragma autonomous_transaction; +begin + update order_tran_coming_in + set success_flag = 'Y' + where order_id = :NEW.order_id; + commit; +end; +/ +BEGIN + INSERT INTO order_tab VALUES(102,SYSDATE,NULL,NULL,1001); + INSERT INTO order_tab VALUES(103,SYSDATE,NULL,NULL,1001); + INSERT INTO order_tab VALUES(103,SYSDATE,NULL,NULL,1001); +EXCEPTION WHEN DUP_VAL_ON_INDEX THEN + ROLLBACK; +END; +/ diff --git a/Chapter09/Chapter09.txt b/Chapter09/Chapter09.txt new file mode 100644 index 0000000..fe2ab99 --- /dev/null +++ b/Chapter09/Chapter09.txt @@ -0,0 +1,320 @@ +-- Bulk DML +DECLARE + Type region_rec IS Record + (region_id NUMBER(4), + region_name VARCHAR2(10)); + Type region_tbl IS TABLE of region_rec + INDEX BY BINARY_INTEGER; + Region_recs region_tbl; + Ret_code NUMBER; + Ret_errmsg VARCHAR2(1000); + Procedure load_regions + (region_recs IN region_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + --Clean up region_tab table initially + DELETE FROM region_tab; + FOR i in region_recs.FIRST..region_recs.LAST LOOP + INSERT INTO region_tab + values (region_recs(i).region_id,region_recs(i).region_name); + END LOOP; + COMMIT; + EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + FOR i IN 1..5 LOOP + Region_recs(i).region_id :=i; + Region_recs(i).region_name :='REGION'||i; + END LOOP; + Load_regions(region_recs,ret_code,ret_errmsg); +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20111,SQLERRM); +END; +/ + +-- The same INSERT operation using Bulk Bind +DECLARE + Type region_id_tbl IS TABLE of NUMBER INDEX BY BINARY_INTEGER; + Type region_name_tbl IS TABLE of VARCHAR2(20)INDEX BY BINARY_INTEGER; + region_ids region_id_tbl; + region_names region_name_tbl; + ret_code NUMBER; + ret_errmsg VARCHAR2(1000); + Procedure load_regions_bulk_bind + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + --clean up the region_tab table initially. + DELETE FROM region_tab; + FORALL i IN region_ids.FIRST..region_ids.LAST + INSERT INTO region_tab values (region_ids(i),region_names(i)); + Retcd :=0; + EXCEPTION WHEN OTHERS THEN + COMMIT; + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + FOR i IN 1..5 LOOP + Region_ids(i):=i; + Region_names(i):='REGION'||i; + END LOOP; + Load_regions_bulk_bind(region_ids,region_names,ret_code,ret_errmsg); +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20112,SQLERRM); +END; +/ + +-- An example showing performance benefit of FORALL +DECLARE + Type region_id_tbl IS TABLE of NUMBER INDEX BY BINARY_INTEGER; + Type region_name_tbl IS TABLE of VARCHAR2(20)INDEX BY BINARY_INTEGER; + region_ids region_id_tbl; + region_names region_name_tbl; + Ret_code NUMBER; + Ret_errmsg VARCHAR2(1000); + time1 number; + time2 number; + time3 number; + Procedure load_regions + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + FOR i in 1..10000 LOOP + INSERT INTO region_tab_temp + values (region_ids(i),region_names(i)); + END LOOP; + COMMIT; + EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; + Procedure load_regions_bulk_bind + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + FORALL i IN 1..10000 + INSERT INTO region_tab_temp values (region_ids(i),region_names(i)); + Retcd :=0; + EXCEPTION WHEN OTHERS THEN + COMMIT; + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + DELETE region_tab_temp; + FOR i IN 1..10000 LOOP + Region_ids(i):=i; + Region_names(i):='REGION'||i; + END LOOP; + time1 :=dbms_utility.get_time; + Load_regions(region_ids,region_names,ret_code,ret_errmsg); + time2 :=dbms_utility.get_time; + Load_regions_bulk_bind(region_ids,region_names,ret_code,ret_errmsg); + time3 :=dbms_utility.get_time; + dbms_output.put_line('Time without bulk bind is '||to_char(time2-time1)|| + ' secs'); + dbms_output.put_line('Time with bulk bind is '||to_char(time3-time2)||'secs'); +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20111,SQLERRM); +END; +/ + +-- A complete example of FORALL with SAVE EXCEPTIONS clause +DECLARE + Type region_id_tbl IS TABLE of NUMBER INDEX BY BINARY_INTEGER; + Type region_name_tbl IS TABLE of VARCHAR2(20)INDEX BY BINARY_INTEGER; + region_ids region_id_tbl; + region_names region_name_tbl; + ret_code NUMBER; + ret_errmsg VARCHAR2(1000); + Procedure load_regions_bulk_bind + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + bulk_bind_excep EXCEPTION; + PRAGMA EXCEPTION_INIT(bulk_bind_excep,-24381); + BEGIN + --clean up the region_tab table initially. + DELETE FROM region_tab; + FORALL i IN region_ids.FIRST..region_ids.LAST SAVE EXCEPTIONS + INSERT INTO region_tab values (region_ids(i),region_names(i)); + Retcd :=0; + EXCEPTION WHEN bulk_bind_excep THEN + FOR i in 1..SQL%BULK_EXCEPTIONS.COUNT LOOP + DBMS_OUTPUT.PUT_LINE('Iteration '|| + SQL%BULK_EXCEPTIONS(i).error_index||'failed with error '|| + SQLERRM(-SQL%BULK_EXCEPTIONS(i).error_code)); + END LOOP; + COMMIT; + Retcd :=SQLCODE; + Errmsg :='Bulk DML error(s)'; + WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + FOR i IN 1..5 LOOP + Region_ids(i):=i; + Region_names(i):='REGION'||i; + END LOOP; + Region_names(3):='REGION WITH NAME3'; + Load_regions_bulk_bind(region_ids,region_names,ret_code,ret_errmsg); +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20112,SQLERRM); +END; +/ + +-- The above example rewritten using SQL%BULK_ROWCOUNT and SQL%ROWCOUNT +DECLARE + Type region_id_tbl IS TABLE of NUMBER INDEX BY BINARY_INTEGER; + Type region_name_tbl IS TABLE of VARCHAR2(20)INDEX BY BINARY_INTEGER; + region_ids region_id_tbl; + region_names region_name_tbl; + ret_code NUMBER; + ret_errmsg VARCHAR2(1000); + Procedure load_regions_bulk_bind + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + FORALL i IN region_ids.FIRST..region_ids.LAST + INSERT INTO region_tab values (region_ids(i),region_names(i)); + FOR i in 1..region_ids.COUNT LOOP + IF SQL%BULK_ROWCOUNT(i)>0 THEN + -- + dbms_output.put_line(to_char(sql%bulk_rowcount(i))); + NULL; + END IF; + END LOOP; + IF SQL%ROWCOUNT =0 THEN + DBMS_OUTPUT.PUT_LINE('No Rows inserted overall'); + ELSE + COMMIT; + END IF; + EXCEPTION WHEN OTHERS THEN + COMMIT; + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + region_ids(1):=6; + region_names(1):='region6'; + load_regions_bulk_bind(region_ids,region_names,ret_code,ret_errmsg); +END; +/ + +-- Bulk Query +-- Procedure update_dyn_global_bulk +Create or Replace Procedure update_dyn_global_bulk + (retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + TYPE NameTbl IS TABLE OF region_tab.region_name%TYPE; + Region_names NameTbl; +BEGIN + SELECT region_name BULK COLLECT INTO region_names + FROM region_tab ORDER BY region_name; + FOR i IN region_names.FIRST..region_names.LAST LOOP + update_dyn_for_all_orders(region_names(i),retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ + +-- Using BULK COLLECT in Fetching +-- Procedure update_dyn_global_bulk2 +Create or Replace Procedure update_dyn_global_bulk2 + (retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + TYPE NameTbl IS TABLE OF region_tab.region_name%TYPE; + Region_names NameTbl; + CURSOR csr_region_names IS + SELECT region_name FROM region_tab ORDER BY region_name; +BEGIN + OPEN csr_region_names; + FETCH csr_region_names BULK COLLECT INTO region_names; + FOR i IN region_names.FIRST..region_names.LAST LOOP + update_dyn_for_all_orders(region_names(i),retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; + CLOSE csr_region_names; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ + +-- Using BULK COLLECT in RETURNING INTO +DECLARE + Type region_id_tbl IS TABLE of NUMBER INDEX BY BINARY_INTEGER; + Type region_name_tbl IS TABLE of VARCHAR2(20)INDEX BY BINARY_INTEGER; + region_ids region_id_tbl; + region_names region_name_tbl; + out_region_names region_name_tbl; + ret_code NUMBER; + ret_errmsg VARCHAR2(1000); + Procedure load_regions_bulk_bind + (region_ids IN region_id_tbl, + region_names IN region_name_tbl, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) + Is + BEGIN + --clean up the sec_region_tab table initially. + DELETE FROM sec_region_tab; + FORALL i IN region_ids.FIRST..region_ids.LAST + INSERT INTO sec_region_tab values (region_ids(i),region_names(i)); + Retcd :=0; + EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; + END; +BEGIN + FOR i IN 1..5 LOOP + Region_ids(i):=i; + Region_names(i):='REGION'||i; + END LOOP; + Load_regions_bulk_bind(region_ids,region_names,ret_code,ret_errmsg); + IF (ret_code <>0) THEN + RAISE_APPLICATION_ERROR(-20111,SQLERRM); + END IF; + FORALL i IN 1..5 + UPDATE sec_region_tab + SET region_name ='NEW '||region_name + WHERE region_id =region_ids(i) + RETURNING region_name BULK COLLECT INTO out_region_names; + FOR i in out_region_names.FIRST..out_region_names.LAST LOOP + DBMS_OUTPUT.PUT_LINE(out_region_names(i)); + END LOOP; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20112,SQLERRM); +END; +/ diff --git a/Chapter10/Chapter10.txt b/Chapter10/Chapter10.txt new file mode 100644 index 0000000..9a761a9 --- /dev/null +++ b/Chapter10/Chapter10.txt @@ -0,0 +1,800 @@ +--Defining an object type +CREATE OR REPLACE TYPE address AS OBJECT + (line1 VARCHAR2(20), + line2 VARCHAR2(20), + city VARCHAR2(20), + state_code VARCHAR2(2), + zip VARCHAR2(13)); + +-- Object instances and initialization +DECLARE + off_add address :=address('19 J','Reading Rd','Edison','NJ','08817'); +BEGIN + DBMS_OUTPUT.PUT_LINE(off_add.line1||' '||off_add.line2); + DBMS_OUTPUT.PUT_LINE(off_add.city||', '||off_add.state_code||' '||off_add.zip); +END; +/ + +-- NULL objects and NULL attributes +DECLARE + v_address address; +BEGIN + --v_address has a value + v_address :=address('27 Mine Brook Rd','#99-A','Edison','NJ','08820'); + v_address :=NULL; -- v_address becomes atomically null. + IF (v_address IS NULL) THEN -- condition returns TRUE + DBMS_OUTPUT.PUT_LINE('v_address is atomically null'); + END IF; +END; +/ +DECLARE + v_address address; +BEGIN + IF (v_address IS NULL) THEN -- Returns TRUE + DBMS_OUTPUT.PUT_LINE('v_address is atomically null '); + END IF; + IF (v_address.line1 IS NULL) THEN -- Returns TRUE + DBMS_OUTPUT.PUT_LINE('line1 is null '); + END IF; + --v_address has a value + v_address :=address('27 Mine Brook Rd','#99-A','Edison','NJ','08820'); + v_address :=NULL;--v_address becomes atomically null. + IF (v_address IS NULL) THEN -- condition returns TRUE + DBMS_OUTPUT.PUT_LINE('v_address is atomically null '); + END IF; + v_address.line1 :='1,Ethel Road'; --raises ACCESS_INTO_NULL +EXCEPTION WHEN ACCESS_INTO_NULL THEN + DBMS_OUTPUT.PUT_LINE('Access Into Null'); +END; +/ + +-- Methods +CREATE OR REPLACE TYPE address AS OBJECT + (line1 VARCHAR2(20), + line2 VARCHAR2(20), + city VARCHAR2(20), + state_code VARCHAR2(2), + zip VARCHAR2(13), + MEMBER FUNCTION get_address RETURN VARCHAR2, + MEMBER PROCEDURE set_address + (ip_line1 VARCHAR2, + ip_line2 VARCHAR2, + ip_city VARCHAR2, + ip_state_code VARCHAR2, + ip_zip VARCHAR2) +); +/ +CREATE OR REPLACE TYPE BODY address AS + MEMBER FUNCTION get_address RETURN VARCHAR2 + IS + BEGIN + RETURN (SELF.line1||' '||SELF.line2||' '||SELF.city||', '|| + SELF.state_code||' '||SELF.zip); + END get_address; + MEMBER PROCEDURE set_address (ip_line1 VARCHAR2, + ip_line2 VARCHAR2, + ip_city VARCHAR2, + ip_state_code VARCHAR2, + ip_zip VARCHAR2) + IS + BEGIN + line1 :=ip_line1; + line2 :=ip_line2; + city :=ip_city; + state_code :=ip_state_code; + zip :=ip_zip; + END set_address; +END; +/ + +-- Invoking a method +DECLARE + off_add address; + home_add address; +BEGIN + off_add :=address('10 Wood Avenue South','Suite 111','Edison','NJ','08830'); + home_add :=address(null,null,null,null,null); + DBMS_OUTPUT.PUT_LINE(off_add.get_address()); + home_add.set_address('161 Franklin Rd','#180','Edison','NJ','08820'); + DBMS_OUTPUT.PUT_LINE(home_add.get_address()); +END; +/ + +-- Static Method +CREATE OR REPLACE TYPE zip_code AS OBJECT +(five_digit_code NUMBER, + four_digit_code NUMBER, + STATIC FUNCTION getZip(zip_in zip_code) RETURN zip_Code +); +/ +CREATE OR REPLACE TYPE BODY zip_code AS + STATIC FUNCTION getZip(zip_in zip_code) RETURN zip_code + IS + v_zip zip_code; + BEGIN + v_zip :=zip_code(null,null); + v_zip.five_digit_code :=zip_in.five_digit_code; + v_zip.four_digit_code :=zip_in.four_digit_code; + RETURN (v_zip); + END; +END; +/ + +-- User-defined constructors +CREATE OR REPLACE TYPE address2 AS OBJECT + (line1 VARCHAR2(20), + line2 VARCHAR2(20), + city VARCHAR2(20), + state_code VARCHAR2(2), + zip VARCHAR2(13), + country VARCHAR(3), + CONSTRUCTOR FUNCTION address2(ip_line1 VARCHAR2, + ip_line2 VARCHAR2, + ip_city VARCHAR2, + ip_state_code VARCHAR2, + ip_zip VARCHAR2) + RETURN SELF AS RESULT); +/ +CREATE OR REPLACE TYPE BODY address2 IS + CONSTRUCTOR FUNCTION address2(ip_line1 VARCHAR2, + ip_line2 VARCHAR2, + ip_city VARCHAR2, + ip_state_code VARCHAR2, + ip_zip VARCHAR2) + RETURN SELF AS RESULT + IS + BEGIN + SELF.line1 :=ip_line1; + SELF.line2 :=ip_line2; + SELF.city :=ip_city; + SELF.state_code :=ip_state_code; + SELF.zip :=ip_zip; + SELF.country :='USA'; + RETURN; + END; +END; +/ +declare + v_address address2; +begin + v_address :=address2('Suite 288','San Street','San Jose','CA','11011'); + dbms_output.put_line(v_address.line1); + dbms_output.put_line(v_address.line2); + dbms_output.put_line(v_address.city||', '||v_address.state_code|| + ' '||v_address.zip); + dbms_output.put_line(v_address.country); +end; +/ + +-- Object tables +CREATE TABLE address_master OF address; +INSERT INTO address_master +VALUES (address('19 J','Reading Rd','Edison','NJ','08817')); +select *from address_master; + +-- Object Relational tables +CREATE TABLE employee +(empid number(10)PRIMARY KEY, + lastname varchar2(30)NOT NULL, + firstname varchar2(30)NOT NULL, + middle_initial varchar2(2), + emp_address address); + +INSERT INTO employee VALUES +(101,'LAKSHMAN','BULUSU',null, +address('50 UNION SQUARE','SUITE 101','NEW YORK','NY','10020')); + +-- Object References +DROP TABLE employee; +CREATE TABLE employee +(empid number(10)PRIMARY KEY, + lastname varchar2(30)NOT NULL, + firstname varchar2(30)NOT NULL, + middle_initial varchar2(2), + emp_address REF address); + + +-- DML on Objects +-- SELECT +DECLARE + v_address address; +BEGIN + SELECT emp_address + INTO v_address + FROM employee + WHERE lastname ='LAKSHMAN'; + DBMS_OUTPUT.PUT_LINE('The address of the employee LAKSHMAN is'); + DBMS_OUTPUT.PUT_LINE(v_address.line1||' '||v_address.line2); + DBMS_OUTPUT.PUT_LINE(v_address.city||', '||v_address.state_code||' '|| + v_address.zip); +END; +/ +SELECT * FROM employee e WHERE e.emp_address.city ='Edison'; +SELECT e.emp_address.get_address() +FROM employee e; + +-- VALUE operator +DECLARE + v_address address; +BEGIN + SELECT VALUE(a) + INTO v_address + FROM address_master a + WHERE a.city ='EDISON'; +END; +/ + +-- REF operator +DECLARE + v_address_ref REF address; +BEGIN + SELECT REF(a) + INTO v_address_ref + FROM address_master a + WHERE a.city ='EDISON'; +END; +/ +DECLARE + v_address_ref REF address; + v_zip VARCHAR2(30); +BEGIN + SELECT REF(a), a.zip + INTO v_address_ref,v_zip + FROM address_master a + WHERE a.city ='EDISON'; +END; +/ + +-- DEREF operator +DECLARE + v_address_ref REF address; + v_address address; +BEGIN + SELECT DEREF(v_address_ref) + INTO v_address + FROM DUAL; +END; +/ +DECLARE + v_address address; +BEGIN + SELECT DEREF(e.emp_address) + INTO v_address + FROM employee e + WHERE e.lastname ='LAKSHMAN'; + DBMS_OUTPUT.PUT_LINE('The address of the employee LAKSHMAN is'); + DBMS_OUTPUT.PUT_LINE(v_address.line1||' '||v_address.line2); + DBMS_OUTPUT.PUT_LINE(v_address.city||', '||v_address.state_code||' '|| + v_address.zip); +END; +/ +UPDATE employee SET emp_address =NULL WHERE emp_address IS DANGLING; + +-- INSERT +DECLARE + v_address_ref REF address; +BEGIN + INSERT INTO address_master a + VALUES (address('57-1 Fairlawn Street','#101C','Flushing','NY','10110')) + RETURNING REF(a)INTO v_address_ref; +END; +/ + +-- UPDATE +UPDATE address_master a SET a.zip ='08820-3307 'WHERE a.zip ='08820'; + +DECLARE + v_address address; + v_address_ref REF address; +BEGIN + INSERT INTO address_master a + VALUES (address('10 Metroplex Complex','Suite 202','Boston','MA','01701')) + RETURNING REF(a)INTO v_address_ref; + UPDATE employee + SET emp_address =v_address_ref + WHERE empid =101; +END; +/ +-- DELETE +BEGIN + DELETE FROM address_master a + WHERE (a.line1 IS NULL)AND (a.line2 IS NULL); +END; +/ + +-- Using %TYPE and %ROWTYPE on Row Objects +DECLARE + v_line1 address_master.line1%TYPE; +BEGIN + SELECT line1 + INTO v_line1 + FROM address_master + WHERE city ='EDISON'; + DBMS_OUTPUT.PUT_LINE(v_line1); +END; +/ +declare + cursor c1 is select VALUE(a)from address_master a; + v_add address_master%ROWTYPE; +begin + open c1; + loop + fetch c1 into v_add; + exit when c1%notfound; + dbms_output.put_line(v_add.line1); + end loop; + close c1; +end; +/ +declare + cursor c1 is select * from address_master; + v_add address_master%ROWTYPE; +begin + for i in c1 loop + dbms_output.put_line(i.line1); + end loop; +end; +/ + +--Objects and Native Dynamic SQL +--Dynamic DDL involving objects +Create or replace Procedure create_dyn_obj_table + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +authid current_user +Is + Dyn_string VARCHAR2(1000); + Dyn_Table_name VARCHAR2(30); +Begin + Dyn_table_name :='ADDRESS_MASTER_FOR_'||replace(trim(i_region_name),' ','_'); + Dyn_string :='CREATE TABLE '||dyn_table_name||'OF address '; + EXECUTE IMMEDIATE dyn_string ; + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR:Creating table '||dyn_table_name ||'-'||SQLERRM; +End; +/ +Create or replace Procedure create_dyn_obj_for_all + (retcd OUT NUMBER,errmsg OUT VARCHAR2) +Authid current_user +Is + CURSOR csr_region IS + SELECT region_name + FROM region_tab; +BEGIN + FOR idx IN csr_region LOOP + create_dyn_obj_table(idx.region_name,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ +DECLARE + Retcd NUMBER; + Errmsg VARCHAR2(32767); +BEGIN + Create_dyn_obj_for_all(retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20190,errmsg); + END IF; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20191,SQLERRM); +END; +/ +column object_name format a30; +select object_name,object_type from user_objects +where object_name like 'ADDRESS%FOR%'; + +-- Dynamic INSERT involving objects +Create or replace Procedure insert_dyn_obj_table + (i_region_name VARCHAR2,i_line1 VARCHAR2, + i_line2 VARCHAR2,i_city VARCHAR2, + i_state_code VARCHAR2,i_zip VARCHAR2, + retcd OUT NUMBER,errmsg OUT VARCHAR2) +authid current_user +Is + Dyn_ins_string VARCHAR2(1000); + Dyn_Table_name VARCHAR2(30); +Begin + Dyn_table_name :='ADDRESS_MASTER_FOR_'||replace(trim(i_region_name),' ','_'); + Dyn_ins_string := + 'INSERT INTO '||dyn_table_name||' VALUES (address(:1,:2,:3,:4,:5))'; + EXECUTE IMMEDIATE dyn_ins_string + USING i_line1,i_line2,i_city,i_state_code,i_zip; + retcd :=0; +EXCEPTION WHEN OTHERS THEN + retcd :=SQLCODE; + errmsg :='ERR: '||SQLERRM; +End; +/ +DECLARE + Retcd NUMBER; + Errmsg VARCHAR2(32767); +BEGIN + insert_dyn_obj_table('REGION1','20 James St.',null,'Edison','NJ','08825', + retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20193,errmsg); + END IF; + insert_dyn_obj_table('REGION1','11 Woodstock Ave.','#2D','Blue Bells','VA', + '17864',retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20194,errmsg); + END IF; + insert_dyn_obj_table('REGION2','15 Highs Blvd','Suite 201','Sunnyvale','CA', + '12456',retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20195,errmsg); + END IF; + insert_dyn_obj_table('REGION4','1 Woodfield Ct.',null,'Dallas','TX', + '94567',retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20196,errmsg); + END IF; + COMMIT; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20197,SQLERRM); +END; +/ + +-- Dynamic multi-row querying involving objects +Create or replace Procedure display_dyn_obj_for_region + (i_region_name VARCHAR2, + retcd OUT NUMBER, + errmsg OUT VARCHAR2) +Is + Dyn_table_name VARCHAR2(100); + Dyn_query_string VARCHAR2(1000); + Type csr_dyn IS REF CURSOR; + csr_dyn1 csr_dyn; + v_address address; +BEGIN + Dyn_table_name :='ADDRESS_MASTER_FOR_'||replace(trim(i_region_name),' ','_'); + Dyn_query_string :='SELECT VALUE(a) FROM '||dyn_table_name||'a '; + DBMS_OUTPUT.PUT_LINE('The addresses for region: '||i_region_name||' are :-'); + DBMS_OUTPUT.NEW_LINE; + OPEN csr_dyn1 FOR dyn_query_string; + LOOP + FETCH csr_dyn1 INTO v_address; + EXIT WHEN csr_dyn1%NOTFOUND; + DBMS_OUTPUT.PUT_LINE(v_address.line1||' '||v_address.line2||' '|| + v_address.city||', '||v_address.state_code||' '||v_address.zip); + END LOOP; + CLOSE csr_dyn1; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ +Create or replace Procedure display_dyn_obj_global + (retcd OUT NUMBER, + errmsg OUT VARCHAR2) +Is + CURSOR csr_region IS + SELECT region_name FROM region_tab; +BEGIN + FOR idx IN csr_region LOOP + display_dyn_obj_for_region(idx.region_name,retcd,errmsg); + IF retcd <>0 THEN + EXIT; + END IF; + END LOOP; +EXCEPTION WHEN OTHERS THEN + Retcd :=SQLCODE; + Errmsg :=SQLERRM; +END; +/ +DECLARE + Retcd NUMBER; + Errmsg VARCHAR2(32767); +BEGIN + display_dyn_obj_global(retcd,errmsg); + IF (retcd <>0) THEN + RAISE_APPLICATION_ERROR(-20190,errmsg); + END IF; +EXCEPTION WHEN OTHERS THEN + RAISE_APPLICATION_ERROR(-20191,SQLERRM); +END; +/ + +-- Constructing a type hierarchy in PL/SQL +CREATE OR REPLACE TYPE book_type AS OBJECT +(title VARCHAR2(50), + author VARCHAR2(30), + ISBN NUMBER, + publisher VARCHAR2(50), + prize_awarded VARCHAR2(1), + NOT INSTANTIABLE MEMBER PROCEDURE display_info +) +NOT INSTANTIABLE +NOT FINAL; +/ +CREATE OR REPLACE TYPE literature_type UNDER book_type +(category VARCHAR2(20), + award_name VARCHAR2(20), + OVERRIDING MEMBER PROCEDURE display_info +) +INSTANTIABLE +NOT FINAL; +/ +CREATE OR REPLACE TYPE fiction_type UNDER literature_type +(based_upon VARCHAR2(20), + OVERRIDING MEMBER PROCEDURE display_info +) +INSTANTIABLE +NOT FINAL; +/ +CREATE OR REPLACE TYPE novel_type UNDER fiction_type +(can_be_filmed VARCHAR2(1), + OVERRIDING MEMBER PROCEDURE display_info +) +INSTANTIABLE +NOT FINAL; +/ +CREATE OR REPLACE TYPE mystery_type UNDER novel_type +(type_of_mystery VARCHAR2(20), + OVERRIDING MEMBER PROCEDURE display_info +) +INSTANTIABLE +FINAL; +/ +CREATE OR REPLACE TYPE BODY literature_type +IS + OVERRIDING MEMBER PROCEDURE display_info + IS + BEGIN + DBMS_OUTPUT.PUT_LINE(rpad('Category',20)||' '||rpad('Books',60)); + DBMS_OUTPUT.PUT_LINE(rpad('-',20,'-')||' '||rpad('-',60,'-')); + DBMS_OUTPUT.PUT_LINE(rpad(SELF.category,20)||' '||SELF.title||' by '|| + SELF.author); + END; +END; +/ +CREATE OR REPLACE TYPE BODY fiction_type +IS + OVERRIDING MEMBER PROCEDURE display_info + IS + BEGIN + DBMS_OUTPUT.PUT_LINE(rpad('Category',20)||' '||rpad('Books',60)); + DBMS_OUTPUT.PUT_LINE(rpad('-',20,'-')||' '||rpad('-',60,'-')); + DBMS_OUTPUT.PUT_LINE(rpad(SELF.category,20)||' '||SELF.title||' by '|| + SELF.author); + DBMS_OUTPUT.PUT_LINE('This title is based upon '||SELF.based_upon); + END; +END; +/ +CREATE OR REPLACE TYPE BODY novel_type +IS + OVERRIDING MEMBER PROCEDURE display_info + IS + v_can_be_filmed VARCHAR2(20); + BEGIN + SELECT decode(SELF.can_be_filmed,'Y','can be filmed', + 'N ','cannot be filmed') + INTO v_can_be_filmed + FROM dual; + DBMS_OUTPUT.PUT_LINE(rpad('Category',20)||' '||rpad('Books',60)); + DBMS_OUTPUT.PUT_LINE(rpad('-',20,'-')||' '||rpad('-',60,'-')); + DBMS_OUTPUT.PUT_LINE(rpad(SELF.category,20)||' '||SELF.title||' by '|| + SELF.author); + DBMS_OUTPUT.PUT_LINE('This title is a novel based upon '||SELF.based_upon|| + ' and '||v_can_be_filmed); + END; +END; +/ +CREATE OR REPLACE TYPE BODY mystery_type +IS + OVERRIDING MEMBER PROCEDURE display_info + IS + v_can_be_filmed VARCHAR2(20); + BEGIN + SELECT decode(SELF.can_be_filmed,'Y','can be filmed', + 'N','cannot be filmed') + INTO v_can_be_filmed + FROM dual; + DBMS_OUTPUT.PUT_LINE(rpad('Category',20)||' '||rpad('Books',60)); + DBMS_OUTPUT.PUT_LINE(rpad('-',20,'-')||' '||rpad('-',60,'-')); + DBMS_OUTPUT.PUT_LINE(rpad(SELF.category,20)||' '||SELF.title||' by '|| + SELF.author); + DBMS_OUTPUT.PUT_LINE('This title is a novel based upon '||SELF.based_upon|| + ', '||v_can_be_filmed|| + ' and is a mystery of '||SELF.type_of_mystery||' type'); + END; +END; +/ +declare + lit_classic literature_type; +begin + lit_classic :=literature_type('DREAMS UNLIMITED','Bulusu Lakshman', + 0112224444,'Books International','Y', + 'Fiction','Booker Prize'); + lit_classic.display_info; +end; +/ +declare + classic_book mystery_type; +begin + classic_book :=mystery_type('DREAMS UNLIMITED','Bulusu Lakshman', + 0112224444,'Books International','Y', + 'Fiction','Booker Prize','Scientific', + 'Y','Medical Related'); + classic_book.display_info; +end; +/ + +-- Dynamic Method Dispatch +declare + lit_classic literature_type; + classic_book mystery_type; +begin + lit_classic :=literature_type('DREAMS UNLIMITED','Bulusu Lakshman', + 0112224444,'Books International','Y', + 'Fiction','Booker Prize'); + lit_classic.display_info; + classic_book :=mystery_type('DREAMS UNLIMITED','Bulusu Lakshman', + 0112224444,'Books International','Y','Fiction', + 'Booker Prize','Scientific','Y','Medical Related'); + classic_book.display_info; +end; +/ + +-- SQL Types of Language Java or SQLJ Object Types +-- Custom Java Class that the SQLJ Object Type maps to +import java.sql.*; +import oracle.sql.*; +public class Address implements SQLData { + public String line1; + public String line2; + public String city; + public String state_code; + public String zip; + String sql_type ="ADDRESS_SQLJ"; + + public Address(){ + } + + public Address (String iline1,String iline2,String icity, + String istate,String izip){ + this.line1 =iline1; + this.line2 =iline2; + this.city =icity; + this.state_code =istate; + this.zip =izip; + } + + public String getSQLTypeName()throws SQLException + { + return sql_type; + } + + public void readSQL(SQLInput stream,String typeName) + throws SQLException + { + sql_type =typeName; + line1 =stream.readString(); + line2 =stream.readString(); + city =stream.readString(); + state_code =stream.readString(); + zip =stream.readString(); + } + + public void writeSQL(SQLOutput stream) + throws SQLException + { + stream.writeString(line1); + stream.writeString(line2); + stream.writeString(city); + stream.writeString(state_code); + stream.writeString(zip); + } + + public static Address setAddress (String iline1,String iline2, + String icity,String istate,String zip){ + return new Address(iline1,iline2,icity,istate,izip); + } + + public String getAddress(){ + return this.line1 +" "+this.line2 +" "+this.city +", "+ + this.state_code +" "+this.zip; + } +} + +-- Creating the SQLJ object type that maps to the above Java class +CREATE TYPE address_sqlj AS OBJECT +EXTERNAL NAME 'Address 'LANGUAGE JAVA +USING SQLData( +line1_sqlj varchar2(20)EXTERNAL NAME 'line1', +line2_sqlj varchar2(20)EXTERNAL NAME 'line2', +city_sqlj varchar2(20)EXTERNAL NAME 'city', +state_code_sqlj varchar2(2)EXTERNAL NAME 'state_code', +zip_sqlj varchar2(13)EXTERNAL NAME 'zip', +STATIC FUNCTION set_address (p_line1 VARCHAR2,p_line2 VARCHAR2, +p_city VARCHAR2,p_state_code VARCHAR2,p_zip VARCHAR2) +RETURN address_sqlj +EXTERNAL NAME 'setAddress (java.lang.String,java.lang.String, +java.lang.String,java.lang.String,java.lang.String) return Address', +MEMBER FUNCTION get_address RETURN VARCHAR2 +EXTERNAL NAME 'Address.getAddress()return java.lang.String' +) +NOT FINAL; +/ + +-- Using the SQLJ Object Type in PL/SQL and/or SQL +CREATE TABLE address_master_sqlj OF address_sqlj; + +insert into address_master_sqlj +values(address_sqlj.set_address('1 Oracle parkway',null,'Redwood Shores', +'CA','41246')); + +SELECT a.line1_sqlj,a.line2_sqlj FROM address_master_sqlj a; + +SELECT a.get_address()FROM address_master_sqlj; + +--User-defined Operators +CREATE OR REPLACE FUNCTION f_eq (p1 VARCHAR2,p2 VARCHAR2) RETURN NUMBER +IS +BEGIN + IF p1 =p2 THEN + RETURN 1; + ELSE + RETURN 0; + END IF; +END f_eq; +/ +CREATE OR REPLACE OPERATOR eq +BINDING (VARCHAR2,VARCHAR2)RETURN NUMBER +USING f_eq; + +CREATE OR REPLACE FUNCTION f_eq1 (p1 VARCHAR2,p2 VARCHAR2) +RETURN BOOLEAN +IS +BEGIN + IF p1 =p2 THEN + RETURN TRUE; + ELSE + RETURN FALSE; + END IF; +END f_eq1; +/ +CREATE OR REPLACE OPERATOR eq1 +BINDING (VARCHAR2,VARCHAR2)RETURN BOOLEAN +USING f_eq1; + +SELECT * FROM employee_test +WHERE EQ(lastname,'SMITH')=1; + +create table test (test number); + +insert into test values (eq('ROBERT','SMITH')); + +select * from test; + +declare + v_empid number; + v_lastname varchar2(30); + v_firstname varchar2(30); +begin + select empid,lastname,firstname + into v_empid,v_lastname,v_firstname + from employee_test + where EQ(lastname,'SMITH')=1; + dbms_output.put_line(to_char(v_empid)||' '||v_lastname||' '||v_firstname); +end; +/ +declare + string1 varchar2(10):='ROBERT'; + string2 varchar2(10):='SMITH'; +begin + if eq(string1,string2)=1 then + dbms_output.put_line('String1 equals String2'); + else + dbms_output.put_line('String1 does not equal String2'); + end if; +end; +/ diff --git a/Chapter11/Chapter11.txt b/Chapter11/Chapter11.txt new file mode 100644 index 0000000..e5f841d --- /dev/null +++ b/Chapter11/Chapter11.txt @@ -0,0 +1,641 @@ +-- Defining a VARRAY +DECLARE + TYPE num_varray IS VARRAY(5)OF NUMBER; + v_numvarray num_varray; +BEGIN + /*Do some processing */ + null; +END; +/ + +-- Initializing a VARRAY +DECLARE + TYPE num_varray IS VARRAY(5)OF NUMBER; + v_numvarray num_varray :=num_varray(10,20,30,40); +BEGIN + dbms_output.put_line('The first element of v_numvarray is '|| + TO_CHAR(v_numvarray(1))); +END; +/ + +-- NULL VARRAYS and NULL Elements +declare + Type num_varray is VARRAY(5)OF NUMBER; + v_numvarray num_varray; +begin + --checking for NULL after declaring and before initializing + if v_numvarray IS NULL then + dbms_output.put_line('v_numvarray is atomically null'); + end if; + v_numvarray :=NULL; + --checking for NULL after explicitly assigning to NULL + if v_numvarray IS NULL then + dbms_output.put_line('v_numvarray is atomically null after assignment'); + end if; +end; +/ +declare + Type num_varray is VARRAY(5)OF NUMBER; + v_numvarray1 num_varray; +begin + if v_numvarray1 IS NULL then + dbms_output.put_line('v_numvarray1 is atomically null'); + end if; + if v_numvarray1(1) IS NULL then + dbms_output.put_line('The first element of v_numvarray1 is null'); + end if; +end; +/ +declare + Type num_varray is VARRAY(5)OF NUMBER; + v_numvarray2 num_varray; +begin + v_numvarray2 :=num_varray(NULL); + --checking for NULL after initialization + if v_numvarray2 IS NULL then + dbms_output.put_line('v_numvarray2 is atomically null'); + else + dbms_output.put_line('v_numvarray2 is not atomically null'); + end if; + if v_numvarray2(1) IS NULL then + dbms_output.put_line('The first element of v_numvarray2 is null'); + end if; +end; +/ + +-- Accessing VARRAY elements +declare + Type num_varray is VARRAY(5)OF NUMBER; + v_numvarray num_varray; +begin + v_numvarray :=num_varray(10,20,30,40); + --Referencing individual elements + dbms_output.put_line('The elements in the v_numvarray are: '); + dbms_output.put_line(to_char(v_numvarray(1))||', '||to_char(v_numvarray(2))|| + ', '||to_char(v_numvarray(3))||', '|| + to_char(v_numvarray(4))); + + --assignment + v_numvarray(4):=60; + dbms_output.put_line('The elements in the v_numvarray are: '); + dbms_output.put_line(to_char(v_numvarray(1))||', '||to_char(v_numvarray(2))|| + ', '||to_char(v_numvarray(3))||', '|| + to_char(v_numvarray(4))); +end; +/ + +-- Defining a Nested Table +DECLARE + TYPE num_table IS TABLE OF NUMBER; + v_numarray num_table; +BEGIN + /*Do some processing */ + null; +END; +/ + +-- Initializing a Nested Table +DECLARE + TYPE num_table IS TABLE OF NUMBER; + v_numarray num_table :=num_table(10,20,30,40); +BEGIN + dbms_output.put_line('The first element of v_numarray is '|| + TO_CHAR(v_numarray(1))); +END; +/ + +-- NULL and Empty Nested Tables and NULL elements +declare + Type num_table is TABLE OF NUMBER; + v_numarray num_table; +begin + --checking for NULL after declaring and before initializing + if v_numarray IS NULL then + dbms_output.put_line('v_numarray is atomically null'); + end if; + v_numarray :=NULL; + --checking for NULL after explicitly assigning to NULL + if v_numarray IS NULL then + dbms_output.put_line('v_numarray is atomically null after assignment'); + end if; +end; +/ +declare + Type num_table is TABLE OF NUMBER; + v_emptyarray num_table :=num_table(); +begin + if v_emptyarray IS NULL then + dbms_output.put_line('v_emptyarray is atomically null'); + else + dbms_output.put_line('v_emptyarray is NOT atomically null'); + end if; +end; +/ +declare + Type num_table is TABLE OF NUMBER; + v_numarray1 num_table; +begin + if v_numarray1 IS NULL then + dbms_output.put_line('v_numarray1 is atomically null'); + end if; + if v_numarray1(1) IS NULL then + dbms_output.put_line('The first element of v_numarray1 is null'); + end if; +end; +/ +declare + Type num_table is TABLE OF NUMBER; + v_numarray2 num_table; +begin + v_numarray2 :=num_table(NULL); + --checking for NULL after initialization + if v_numarray2 IS NULL then + dbms_output.put_line('v_numarray2 is atomically null'); + else + dbms_output.put_line('v_numarray2 is not atomically null'); + end if; + if v_numarray2(1) IS NULL then + dbms_output.put_line('The first element of v_numarray2 is null'); + end if; +end; +/ + +-- Accessing Nested Table elements +declare + Type num_table is TABLE OF NUMBER; + v_numarray num_table; +begin + v_numarray :=num_table(10,20,30,40); + --Referencing individual elements + dbms_output.put_line('The elements in the v_numarray are: '); + dbms_output.put_line(to_char(v_numarray(1))||', '||to_char(v_numarray(2))|| + ', '||to_char(v_numarray(3))||', '|| + to_char(v_numarray(4))); + + --assignment + v_numarray(4):=50; + dbms_output.put_line('The elements in the v_numarray are: '); + dbms_output.put_line(to_char(v_numarray(1))||', '||to_char(v_numarray(2))|| + ', '||to_char(v_numarray(3))||', '|| + to_char(v_numarray(4))); +end; +/ +declare + Type num_table is TABLE OF NUMBER; + v_numarray num_table; +begin + v_numarray :=num_table(10,20,30,40); + --Referencing individual elements + dbms_output.put_line('The elements in the v_numarray are: '); + dbms_output.put_line(to_char(v_numarray(1))||', '||to_char(v_numarray(2))|| + ', '||to_char(v_numarray(3))||', '|| + to_char(v_numarray(4))); + dbms_output.put_line(to_char(v_numarray(5))); +end; +/ + +-- Collection Methods +-- EXISTS +DECLARE + TYPE num_varray IS VARRAY(5)OF NUMBER; + v_numarray num_varray :=num_varray(10,20,30,40,50); +BEGIN + IF v_numarray.EXISTS(4) THEN + DBMS_OUTPUT.PUT_LINE('The element 4 exists in the variable array.'); + END IF; +END; +/ + +-- COUNT +DECLARE + TYPE num_varray IS VARRAY(10)OF NUMBER; + v_numarray num_varray :=num_varray(10,20,30,40,50); + TYPE num_table IS TABLE OF NUMBER; + v_numlist num_table :=num_table(101,201,301,401); +BEGIN + DBMS_OUTPUT.PUT_LINE('Varray Count = '||TO_CHAR(v_numarray.COUNT)); + DBMS_OUTPUT.PUT_LINE('Nested Table Count = '||TO_CHAR(v_numlist.COUNT)); +END; +/ + +-- LIMIT +DECLARE + TYPE num_varray IS VARRAY(10)OF NUMBER; + v_numarray num_varray :=num_varray(10,20,30); +BEGIN + DBMS_OUTPUT.PUT_LINE('Varray Count = '||TO_CHAR(v_numarray.COUNT)); + DBMS_OUTPUT.PUT_LINE('Varray Limit = '||TO_CHAR(v_numarray.LIMIT)); +END; +/ + +-- EXTEND +DECLARE + TYPE num_varray IS VARRAY(10)OF NUMBER; + v_numarray num_varray :=num_varray(NULL,NULL); + TYPE num_table IS TABLE OF NUMBER; + v_numlist num_table :=num_table(NULL); +BEGIN + v_numarray(1):=1001; + v_numarray(2):=1002; + v_numarray.EXTEND; + v_numarray(3):=1003; + + v_numlist(1):=101; + v_numlist.EXTEND(5); + v_numlist(5):=105; +END; +/ + +-- Collections in the database +CREATE OR REPLACE TYPE num_varray IS VARRAY(10)OF NUMBER; +/ +CREATE OR REPLACE TYPE num_table IS TABLE OF NUMBER; +/ + +-- Stored VARRAYS +CREATE OR REPLACE TYPE add_list AS VARRAY(10)OF NUMBER(10); +/ +CREATE TABLE direct_address_list (list_id VARCHAR2(6)PRIMARY KEY, + direct_addresses add_list ); +-- DML on whole VARRAYS +-- INSERT +INSERT INTO direct_address_list VALUES +('OFF101',add_list(1001,1002,1003,1004)); + +DECLARE + v_add_varray add_list :=add_list(2001,2002); +BEGIN + INSERT INTO direct_address_list VALUES ('OFF102',v_add_varray); +END; +/ + +-- UPDATE +DECLARE + v_add_varray add_list :=add_list(1011,1012,1013); +BEGIN + UPDATE direct_address_list + SET direct_addresses =v_add_varray + WHERE list_id ='OFF102'; +END; +/ + +UPDATE direct_address_list +SET direct_addresses =add_list(1011,1012,1013) +WHERE list_id ='OFF102'; + +-- DELETE +DELETE FROM direct_address_list +WHERE list_id ='OFF102'; + +-- SELECT +DECLARE + v_add_varray direct_address_list.direct_addresses%TYPE; +BEGIN + SELECT direct_addresses + INTO v_add_varray + FROM direct_address_list + WHERE list_id ='OFF101'; + DBMS_OUTPUT.PUT_LINE ( + 'The address list for OFF101 contains the following address IDs :'); + FOR idx IN 1..v_add_varray.COUNT LOOP + DBMS_OUTPUT.PUT_LINE(TO_CHAR(v_add_varray(idx))); + END LOOP; +EXCEPTION WHEN OTHERS THEN + DBMS_OUTPUT.PUT_LINE(SQLERRM); +END; +/ + +SELECT list_id,column_value +FROM direct_address_list,TABLE(direct_addresses); + +-- Stored Nested Tables +CREATE OR REPLACE TYPE home_add_list AS TABLE OF NUMBER(10); +/ +CREATE TABLE home_address_list (list_id VARCHAR2(6)PRIMARY KEY, + home_addresses home_add_list ) +NESTED TABLE home_addresses STORE AS home_addreses_tab; + +-- DML on whole Nested Tables +-- INSERT +INSERT INTO home_address_list VALUES +('H101',home_add_list(1001,1002,1003,1004)); + +DECLARE + v_add_list home_add_list :=home_add_list(2001,2002); +BEGIN + INSERT INTO home_address_list VALUES ('H102',v_add_list); +END; +/ + +-- UPDATE +DECLARE + v_add_list home_add_list :=home_add_list(1011,1012,1013); +BEGIN + UPDATE home_address_list + SET home_addresses =v_add_list + WHERE list_id ='H102'; +END; +/ + +UPDATE home_address_list +SET home_addresses=home_add_list(1011,1012,1013) +WHERE list_id ='H102'; + +-- DELETE +DELETE FROM home_address_list +WHERE list_id ='H102'; + +-- SELECT +DECLARE + v_add_list home_add_list :=home_add_list(2001,2002); +BEGIN + INSERT INTO home_address_list VALUES ('H102',v_add_list); +END; +/ +DECLARE + v_add_list home_address_list.home_addresses%TYPE; +BEGIN + SELECT home_addresses + INTO v_add_list + FROM home_address_list + WHERE list_id ='H102'; + DBMS_OUTPUT.PUT_LINE ( + 'The home address list for H102 contains the following address IDs :'); + FOR idx IN 1..v_add_list.COUNT LOOP + DBMS_OUTPUT.PUT_LINE(TO_CHAR(v_add_list(idx))); + END LOOP; +EXCEPTION WHEN OTHERS THEN + DBMS_OUTPUT.PUT_LINE(SQLERRM); +END; +/ + +SELECT * +FROM TABLE(SELECT home_addresses FROM home_address_list WHERE list_id ='H101'); + +create table num_tab (col1 number(10)); + +declare + v_add_list home_add_list :=home_add_list(NULL,NULL,NULL); +begin + v_add_list(1):=1001; + v_add_list(2):=1002; + v_add_list(3):=1003; + insert into num_tab + select column_value + from TABLE(CAST(v_add_list AS home_add_list)); +end; +/ + +select * from num_tab; + +-- Table Functions +create or replace type num_table is table of number; +/ +create or replace function f_table return num_table +is + v_numarray num_table :=num_table(); +begin + FOR i in 1..10 loop + v_numarray.EXTEND; + v_numarray(i):=i+100; + END LOOP; + RETURN (v_numarray); +end; +/ + +SELECT * FROM TABLE(f_table); + +-- Table Functions involving Object Types +CREATE TYPE temp_adds IS TABLE OF address; +/ + +CREATE OR REPLACE FUNCTION f_table_obj RETURN temp_adds +IS + v_temp_adds temp_adds :=temp_adds(); +BEGIN + v_temp_adds.EXTEND(5); + v_temp_adds(1):= + address('20 Spring St.',null,'New York','NY','10020','USA'); + v_temp_adds(2):= + address('Suite 206','Prospect Blvd','Bloomington','IL','60610','USA'); + v_temp_adds(3):= + address('1 Woodlake Dr.',null,'Piscataway','NJ','08540','USA'); + v_temp_adds(4):= + address('#9','Hayes Avenue','Dallas','TX','11134','USA'); + v_temp_adds(5):= + address('1 Franklin Ct.',null,'Franklin','MA','17012','USA'); + RETURN (v_temp_adds); +END; +/ + +SELECT * FROM TABLE(f_table_obj); + +-- Pipelined Table Functions +CREATE OR REPLACE FUNCTION f_table_obj_pipelined +RETURN temp_adds PIPELINED +IS + v_address address; +BEGIN + FOR i IN 1..5 LOOP + IF (i=1) THEN + v_address := + address('20 Spring St.',null,'New York','NY','10020','USA'); + ELSIF (i=2) THEN + v_address := + address('Suite 206','Prospect Blvd','Bloomington','IL','60610','USA'); + ELSIF (i=3) THEN + v_address := + address('1 Woodlake Dr.',null,'Piscataway','NJ','08540','USA'); + ELSIF (i=4) THEN + v_address := + address('#9','Hayes Avenue','Dallas','TX','11134','USA'); + ELSIF (i=5) THEN + v_address := + address('1 Franklin Ct.',null,'Franklin','MA','17012','USA'); + END IF; + PIPE ROW(v_address); + END LOOP; + RETURN; +END; +/ + +SELECT * FROM TABLE(f_table_obj_pipelined); + +-- A pipelined Table Function that returns a PL/SQL type +CREATE OR REPLACE PACKAGE pkg_table_func +IS + TYPE address_rec IS RECORD + (LINE1 VARCHAR2(20), + LINE2 VARCHAR2(20), + CITY VARCHAR2(20), + STATE_CODE VARCHAR2(2), + ZIP VARCHAR2(13), + COUNTRY_CODE VARCHAR2(4)); + + TYPE temp_adds IS TABLE OF address_rec; +END; +/ + +CREATE OR REPLACE FUNCTION f_table_plsql_pipelined +RETURN pkg_table_func.temp_adds +PIPELINED +IS + v_address pkg_table_func.address_rec; +BEGIN + FOR i IN 1..3 LOOP + IF (i=1) THEN + v_address.line1 :='20 Spring St.'; + v_address.line2 :=null; + v_address.city :='New York'; + v_address.state_code :='NY'; + v_address.zip :='10020'; + v_address.country_code :='USA'; + ELSIF (i=2) THEN + v_address.line1 :='Suite 206'; + v_address.line2 :='Prospect Blvd'; + v_address.city :='Bloomington'; + v_address.state_code :='IL'; + v_address.zip :='60610'; + v_address.country_code :='USA'; + ELSIF (i=3) THEN + v_address.line1 :='1 Woodlake Dr.'; + v_address.line2 :=null; + v_address.city :='Piscataway'; + v_address.state_code :='NJ'; + v_address.zip :='08540'; + v_address.country_code :='USA'; + END IF; + PIPE ROW(v_address); + END LOOP; + RETURN; +END; +/ + +SELECT * FROM TABLE(f_table_plsql_pipelined); + +-- Passing data from one table function to another +-- in a pipelined fashion +CREATE OR REPLACE FUNCTION f_table_plsql2_pipelined(p_ref_cursor SYS_REFCURSOR) +RETURN pkg_table_func.temp_adds PIPELINED +IS + v_address1 pkg_table_func.address_rec; + v_address2 pkg_table_func.address_rec; +BEGIN + LOOP + FETCH p_ref_cursor INTO v_address1; + EXIT WHEN p_ref_cursor%NOTFOUND; + IF (v_address1.city='New York') THEN + v_address2.line1 :='P.O.Box 2215'; + v_address2.line2 :=null; + v_address2.city :='New York'; + v_address2.state_code :='NY'; + v_address2.zip :='10020-2215'; + v_address2.country_code :='USA'; + ELSIF (v_address1.city='Bloomington') THEN + v_address2.line1 :='P.O.Box 6615'; + v_address2.line2 :=null; + v_address2.city :='Bloomington'; + v_address2.state_code :='IL'; + v_address2.zip :='60610-6615'; + v_address2.country_code :='USA'; + ELSIF (v_address1.city='Piscataway') THEN + v_address2.line1 :='P.O.Box 0001'; + v_address2.line2 :=null; + v_address2.city :='Piscataway'; + v_address2.state_code :='NJ'; + v_address2.zip :='08540'; + v_address2.country_code :='USA'; + END IF; + PIPE ROW(v_address2); + END LOOP; + close p_ref_cursor; + RETURN; +END; +/ + +SELECT * FROM TABLE(f_table_plsql2_pipelined( + CURSOR(SELECT * FROM TABLE(f_table_plsql_pipelined())))); + +-- Multilevel Collections +CREATE OR REPLACE TYPE varray_one IS VARRAY(10)OF NUMBER; +/ +CREATE OR REPLACE TYPE varray_one_nested IS VARRAY(10)OF varray_one; +/ +CREATE OR REPLACE TYPE varray_two_nested IS VARRAY(10)OF varray_one_nested; +/ + +DECLARE + v1 varray_one; + v2 varray_one_nested; + v3 varray_two_nested; +BEGIN + v1 :=varray_one(1,2,3); + v2 :=varray_one_nested(varray_one(11,12,13),varray_one(21,22,23)); + v3 :=varray_two_nested( + varray_one_nested(varray_one(111,112,113),varray_one(121,122,123)), + varray_one_nested(varray_one(211,212,213),varray_one(221,222,223))); + dbms_output.put_line('The elements of one-dimensional VARRAY v1 are:'); + for i in 1..v1.count loop + dbms_output.put_line(v1(i)); + end loop; + dbms_output.put_line('The elements of two-dimensional VARRAY v2 are:'); + for i in 1..v2.count loop + for j in 1..v2(i).count loop + dbms_output.put_line(v2(i)(j)); + end loop; + end loop; + dbms_output.put_line('The elements of three-dimensional VARRAY v3 are:'); + for i in 1..v3.count loop + for j in 1..v3(i).count loop + for k in 1..v3(i)(j).count loop + dbms_output.put_line(v3(i)(j)(k)); + end loop; + end loop; + end loop; +END; +/ +DECLARE + TYPE varray_one IS VARRAY(10)OF NUMBER; + TYPE varray_one_nested IS VARRAY(10)OF varray_one; + TYPE varray_two_nested IS VARRAY(10)OF varray_one_nested; + v1 varray_one; + v2 varray_one_nested; + v3 varray_two_nested; +BEGIN + /*Continue further logic */ + null; +END; +/ +DECLARE + TYPE varray_one IS VARRAY(10)OF NUMBER; + TYPE varray_one_nested IS VARRAY(10)OF varray_one; + TYPE varray_two_nested IS VARRAY(10)OF varray_one_nested; + v1 varray_one; + v2 varray_one_nested; + v3 varray_two_nested; +BEGIN + v1 :=varray_one(1,2,3); + v2 :=varray_one_nested(varray_one(11,12,13),varray_one(21,22,23)); + v3 :=varray_two_nested( + varray_one_nested(varray_one(111,112,113),varray_one(121,122,123)), + varray_one_nested(varray_one(211,212,213),varray_one(221,222,223))); + dbms_output.put_line('The elements of one-dimensional VARRAY v1 are:'); + for i in 1..v1.count loop + dbms_output.put_line(v1(i)); + end loop; + dbms_output.put_line('The elements of two-dimensional VARRAY v2 are:'); + for i in 1..v2.count loop + for j in 1..v2(i).count loop + dbms_output.put_line(v2(i)(j)); + end loop; + end loop; + dbms_output.put_line('The elements of three-dimensional VARRAY v3 are:'); + for i in 1..v3.count loop + for j in 1..v3(i).count loop + for k in 1..v3(i)(j).count loop + dbms_output.put_line(v3(i)(j)(k)); + end loop; + end loop; + end loop; +END; +/ diff --git a/Chapter12/Chapter12.txt b/Chapter12/Chapter12.txt new file mode 100644 index 0000000..5dd4158 --- /dev/null +++ b/Chapter12/Chapter12.txt @@ -0,0 +1,267 @@ +-- BLOBS +CREATE TABLE blob_tab +(id NUMBER PRIMARY KEY, + blob_data BLOB); + +INSERT INTO blob_tab VALUES (1,null); + +UPDATE blob_tab +SET blob_data =EMPTY_BLOB() +WHERE id =1; + +INSERT INTO blob_tab VALUES (2,HEXTORAW('ABCDEFABCDEFABCDEF')); + +DECLARE + v_blob BLOB; +BEGIN + INSERT INTO blob_tab VALUES (3,HEXTORAW('ABCDEFABCDEFABCDEF')); + SELECT blob_data + INTO v_blob + FROM blob_tab + WHERE id =3; + /*...Use this blob locator to populate the BLOB with large binary data.*/ +END; +/ +DECLARE + v_blob BLOB; +BEGIN + INSERT INTO blob_tab VALUES (4,HEXTORAW('ABCDEFABCDEFABCDEF')) + RETURNING blob_data INTO v_blob; + /*...Use this blob locator to populate the BLOB with large binary data.*/ +END; +/ + +-- CLOBS +CREATE TABLE clob_tab +(id NUMBER PRIMARY KEY, + clob_data CLOB); + +INSERT INTO clob_tab VALUES (101,null); + +UPDATE clob_tab +SET clob_data =EMPTY_CLOB() +WHERE id =101; + +INSERT INTO clob_tab VALUES (102,RPAD('ABCDEFABCDEFABCDEF',40000,'A')); + +DECLARE + v_clob CLOB; +BEGIN + INSERT INTO clob_tab VALUES (103,EMPTY_CLOB()); + SELECT clob_data + INTO v_clob + FROM clob_tab + WHERE id =103; + /*...Use this clob locator to populate the CLOB with large character data.*/ +END; +/ +DECLARE + v_clob CLOB; +BEGIN + INSERT INTO clob_tab VALUES (104,EMPTY_CLOB()) + RETURNING clob_data INTO v_clob; + /*...Use this clob locator to populate the CLOB with large character data.*/ +END; +/ + +-- BFILES +CREATE TABLE bfile_tab +(id NUMBER PRIMARY KEY, + bfile_data BFILE); + +INSERT INTO bfile_tab VALUES (201,null); + +INSERT INTO bfile_tab VALUES (202,BFILENAME('BFILE_DIR','test.bmp')); + +CREATE DIRECTORY bfile_dir AS 'c:\proj'; +GRANT READ ON DIRECTORY BFILE_DIR TO PLSQL9I; + +DECLARE + v_bfile BFILE; +BEGIN + INSERT INTO bfile_tab VALUES (203,BFILENAME('BFILE_DIR','test.bmp')); + SELECT bfile_data + INTO v_bfile + FROM bfile_tab + WHERE id =203; + /*...Use this bfile locator to read the BFILE */ +END; +/ + +DECLARE + v_bfile BFILE; +BEGIN + INSERT INTO bfile_tab VALUES (204,BFILENAME('BFILE_DIR','test.bmp')) + RETURNING bfile_data INTO v_bfile; + /*...Use this bfile locator to read the BFILE */ +END; +/ + +-- DBMS_LOB Package +-- Populating a BLOB column from an external BFILE +DECLARE + bfile_loc BFILE; + blob_loc BLOB; + bfile_offset NUMBER :=1; + blob_offset NUMBER :=1; + tot_len INTEGER; +BEGIN + --First INSERT a row with an empty blob + INSERT INTO blob_tab VALUES (5,EMPTY_BLOB()); + COMMIT; + --SELECT the blob locator FOR UPDATE + SELECT blob_data INTO blob_loc FROM blob_tab + WHERE id =5 FOR UPDATE; + --Obtain the BFILE locator + bfile_loc :=bfilename('BFILE_DIR','test.bmp'); + --Open the input BFILE */ + dbms_lob.fileopen(bfile_loc,dbms_lob.file_readonly); + --Open the BLOB + dbms_lob.OPEN(blob_loc,dbms_lob.lob_readwrite); + --Populate the blob with the whole bfile data + dbms_lob.LOADBLOBFROMFILE(blob_loc,bfile_loc,dbms_lob.lobmaxsize,bfile_offset, + blob_offset); + --Obtain length of the populated BLOB + tot_len :=DBMS_LOB.GETLENGTH(blob_loc); + --Close the BLOB + dbms_lob.close(blob_loc); + --Close the BFILE + dbms_lob.fileclose(bfile_loc); + COMMIT; + --Display the length of the BLOB + DBMS_OUTPUT.PUT_LINE('The length of the BLOB after population is: '|| + TO_CHAR(tot_len)); +END; +/ + +-- Reading and Writing to a CLOB +declare + clob_loc CLOB; + v_buf VARCHAR2(1000); + Amount BINARY_INTEGER :=1000; + Position INTEGER :=1; +BEGIN + v_buf :=rpad('A',1000,'A'); + insert into clob_tab values (5,EMPTY_CLOB()); + commit; + SELECT clob_data INTO clob_loc + FROM clob_tab + WHERE id =5 FOR UPDATE; + DBMS_LOB.OPEN (clob_loc,DBMS_LOB.LOB_READWRITE); + FOR i IN 1..500 LOOP + DBMS_LOB.WRITE (clob_loc,Amount,Position,v_buf); + Position :=Position +Amount; + END LOOP; + DBMS_LOB.CLOSE (clob_loc); +END; +/ +DECLARE + clob_loc CLOB; + v_Buf VARCHAR2(1000); + Amount BINARY_INTEGER :=1000; + Position INTEGER :=1; + fp UTL_FILE.FILE_TYPE; +BEGIN + --Select the CLOB locator for row with id 5 in clob_tab table + SELECT clob_data INTO clob_loc + FROM clob_tab WHERE id =5; + --Open the CLOB + if (DBMS_LOB.ISOPEN(clob_loc)!=1) then + DBMS_LOB.OPEN (clob_loc,DBMS_LOB.LOB_READONLY); + end if; + --Open the output file for writing + fp :=UTL_FILE.FOPEN('BFILE_DIR','output.dat','w'); + --Read from the CLOB in chunks of 1000 characters and write to the output file + LOOP + BEGIN + DBMS_LOB.READ (clob_loc,Amount,Position,v_Buf); + UTL_FILE.PUT_LINE(fp,v_Buf,TRUE); + Position :=Position +Amount; + EXCEPTION + WHEN NO_DATA_FOUND THEN --This indicates end of data in CLOB + EXIT; + END; + END LOOP; + --Close the output file + UTL_FILE.FCLOSE(fp); + --Close the CLOB + DBMS_LOB.CLOSE (clob_loc); +END; +/ + +-- Getting the Length of a BFILE +declare + bfile_loc BFILE; + tot_len INTEGER; +begin + INSERT INTO bfile_tab VALUES (5,BFILENAME('BFILE_DIR','test.bmp')); + COMMIT; + SELECT bfile_data + INTO bfile_loc + FROM bfile_tab + WHERE id =5; + IF (DBMS_LOB.FILEEXISTS(bfile_loc)!=0) THEN + IF (DBMS_LOB.FILEISOPEN(bfile_loc)!=1) THEN + DBMS_LOB.FILEOPEN(bfile_loc,DBMS_LOB.FILE_READONLY); + tot_len :=DBMS_LOB.GETLENGTH(bfile_loc); + END IF; + END IF; + DBMS_LOB.FILECLOSE(bfile_loc); + DBMS_OUTPUT.PUT_LINE('The size of the external BMP file is '||TO_CHAR(tot_len)); +END; +/ + +-- TO_LOB Function +CREATE TABLE long_test (id NUMBER,long_data LONG); + +INSERT INTO long_test VALUES (100,RPAD('A',200000,'A')); + +CREATE TABLE lob_test (id NUMBER,clob_data CLOB); + +INSERT INTO lob_test + SELECT id,TO_LOB(long_data) + FROM long_test; + +/*DROP TABLE long_test;*/ + +declare + x long :=rpad('A',100000,'B'); + y clob; +begin + y :=to_lob(x); + insert into lob_test values (200,y); +end; +/ + +update lob_test set clob_data =(select to_lob(long_data)from + long_test where id =100) +where id =200; + +-- Copying LONG to LOB with the ALTER TABLE...MODIFY statement +CREATE TABLE long_test1 (id NUMBER,long_data LONG); + +INSERT INTO long_test1 VALUES (100,RPAD('A',200000,'A')); + +ALTER TABLE long_test1 MODIFY (long_data CLOB); + +-- Copying LONG to LOB with the TO_CLOB and TO_BLOB functions +declare + x long; + y clob; +begin + select long_data + into x + from long_test + where id =100; + y :=to_clob(x); + insert into lob_test values (200,y); +end; +/ +declare + x varchar2(32767):=rpad('A',32767,'B'); + y clob; +begin + y :=to_clob(x); + insert into lob_test values (200,y); +end; +/ diff --git a/Chapter12/test.bmp b/Chapter12/test.bmp new file mode 100644 index 0000000..55dfe21 Binary files /dev/null and b/Chapter12/test.bmp differ diff --git a/Chapter13/Chapter13.txt b/Chapter13/Chapter13.txt new file mode 100644 index 0000000..5cca782 --- /dev/null +++ b/Chapter13/Chapter13.txt @@ -0,0 +1,502 @@ +-- Directory.java Class +import java.io.*; +public class Directory +{ + public static String []list(String dirName) + { + String []files =null; + File file =new File(dirName); + if (file.exists()) + { + if (file.isDirectory()) + { + if (file.canRead()) + { + files =file.list(); + } + } + } + return files; + } +} + +-- DirMain.java class +import java.io.*; +public class DirMain +{ + public static void main(String args []) + { + String []fileNames; + //listing of directory + fileNames =Directory.list("C:\\lax\\plsql9i\\latest"); + if (fileNames !=null) + { + for (int i=0;i0) + { + for (int i=0;i + +Organization Records + + +

Organization Records

+ + + + + + + + + + +
HierarchyOrg Long Name
DirectorOffice of Director Tech ABC Inc.
DirectorOffice of Dir.SSL
+ + + +-- Procedure p_test +CREATE OR REPLACE PROCEDURE p_test +IS +BEGIN + htp.p(''); + htp.p(''); + htp.p('Organization Records'); + htp.p(''); + htp.p(''); + htp.p('

Organization Records

'); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + htp.p('
HierarchyOrg Long Name
DirectorOffice of Director Tech ABC Inc.
DirectorOffice of Dir.SSL
'); + htp.p(''); + htp.p(''); +end; +/ + +-- Procedure p_displayOrgs +CREATE OR REPLACE PROCEDURE p_displayOrgs +IS +BEGIN + htp.p(''); + htp.p(''); + htp.p('Organization Records'); + htp.p(''); + htp.p(''); + htp.p('

Organization Records

'); + htp.p(''); + htp.p(''); + for idx in (select h.hrc_descr,o.org_long_name + from org_tab o,hrc_tab h + where o.hrc_code =h.hrc_code + order by h.hrc_code )loop + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + end loop; + htp.p('
HierarchyOrg Long Name
'||idx.hrc_descr||''||idx.org_long_name||'
'); + htp.p(''); + htp.p(''); +end; +/ + +-- Procedure p_displayOrgs_with_param +CREATE OR REPLACE PROCEDURE p_displayOrgs_with_param(ip_hrc_code NUMBER) +IS +BEGIN + htp.p(''); + htp.p(''); + htp.p('Organization Records'); + htp.p(''); + htp.p(''); + htp.p('

Organization Records

'); + htp.p(''); + htp.p(''); + for idx in (select h.hrc_descr,o.org_long_name + from org_tab o,hrc_tab h + where o.hrc_code =h.hrc_code + and h.hrc_code =ip_hrc_code + order by h.hrc_code )loop + htp.p(''); + htp.p(''); + htp.p(''); + htp.p(''); + end loop; + htp.p('
HierarchyOrg Long Name
'||idx.hrc_descr||''||idx.org_long_name||'
'); + htp.p(''); + htp.p(''); +end; +/ + +-- An HTML form to accept user input + + +Organization Records + + +

Organization Records

+

Enter Hrc Code and Press the Run button.

+
+

Hrc Code + +

+

+ +

+
+ + + +-- Procedure p_displayOrgs_with_param_form +CREATE OR REPLACE PROCEDURE p_displayOrgs_with_param_form +IS +BEGIN + htp.p(''); + htp.p(''); + htp.p('Organization Records'); + htp.p(''); + htp.p(''); + htp.p('

Organization Records

'); + htp.p('

Enter Hrc Code and Press the Run button.

'); + htp.p('
'); + htp.p('

Hrc Code + +

'); + htp.p('

+ +

'); + htp.p('
'); + htp.p(''); + htp.p(''); +end; +/ + +-- procedure p_displayOrgs rewritten as a PSP +<%@page language="PL/SQL"%> +<%@plsql procedure="p_displayOrgs_psp"%> +; + +Organization Records + + +

Organization Records

+ + +<% + for idx in (select h.hrc_descr,o.org_long_name + from org_tab o,hrc_tab h + where o.hrc_code =h.hrc_code + order by h.hrc_code )loop +%> + + + + +<%end loop;%> +
HierarchyOrg Long Name
<%=idx.hrc_descr %><%=idx.org_long_name %>
+ + + +-- PSP code for user-interface of Web Application +<%@page language="PL/SQL"%> +<%@plsql procedure="p_webapporg_psp"%> + + +Organization Web Page + + +

Add,Modify or Delete Organizations

+

Enter Hrc Code,Org Id,Short Name,Long Name and click on + ADD,MODIFY or DELETEbuttons

+
+

+Hrc Code: 
+Org Id: 
+Short Name: 
+Long Name: 
+

+ + + +
+ + + +-- Business Logic for Web Application +CREATE OR REPLACE PACKAGE WebAppOrg +IS + PROCEDURE insertOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2); + + PROCEDURE updateOrg(ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2); + + PROCEDURE deleteOrg(ip_org_id NUMBER); + + PROCEDURE run (ip_op VARCHAR2, + ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2); +END WebAppOrg; +/ +CREATE OR REPLACE PACKAGE BODY WebAppOrg +IS + --Procedure to delete records from the org_site_tab table + --before deleting from org_table.This procedure is called + --from the deleteOrg procedure + PROCEDURE deleteOrgSites(ip_org_id NUMBER, + op_retcd OUT NUMBER, + op_err_msg OUT VARCHAR2) + IS + BEGIN + DELETE org_site_tab WHERE org_id =ip_org_id; + op_retcd :=0; + EXCEPTION WHEN OTHERS THEN + op_retcd :=SQLCODE; + op_err_msg :=SQLERRM; + END deleteOrgSites; + + --Procedure to insert a new record in the org_tab table + PROCEDURE insertOrg (ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2) + IS + BEGIN + INSERT INTO org_tab VALUES + (ip_hrc_code,ip_org_id,ip_org_short_name,ip_org_long_name); + htp.p('Organization with Id '||TO_CHAR(ip_org_id)|| + 'successfully inserted.'); + EXCEPTION WHEN DUP_VAL_ON_INDEX THEN + htp.p('Organization with Id '||TO_CHAR(ip_org_id)||'already exists.'); + WHEN OTHERS THEN + htp.p(SQLERRM); + END insertOrg; + + --Procedure to modify the long and short names for a + --given org_id in the org_tab table + PROCEDURE updateOrg(ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2) + IS + BEGIN + UPDATE org_tab + SET org_short_name =ip_org_short_name, + org_long_name =ip_org_long_name + WHERE org_id =ip_org_id; + IF (SQL%NOTFOUND)THEN + htp.p('Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'); + RETURN; + END IF; + htp.p('Organization with Id '||TO_CHAR(ip_org_id)|| + 'successfully modified.'); + EXCEPTION WHEN OTHERS THEN + htp.p(SQLERRM); + END updateOrg; + + --Procedure to delete a record from the org_tab table + PROCEDURE deleteOrg(ip_org_id NUMBER) + IS + op_retcd NUMBER; + op_err_msg VARCHAR2(1000); + BEGIN + deleteOrgSites(ip_org_id,op_retcd,op_err_msg); + IF (op_retcd <>0)then + htp.p('Delete of Org Sites failed with error '||op_err_msg); + RETURN; + END IF; + DELETE org_tab WHERE org_id =ip_org_id; + IF (SQL%NOTFOUND)THEN + htp.p('Organization with Id '||TO_CHAR(ip_org_id)|| + 'does not exist.'); + RETURN; + END IF; + htp.p('Organization with Id '||TO_CHAR(ip_org_id)||'successfully deleted.'); + EXCEPTION WHEN OTHERS THEN + htp.p(SQLERRM); + END deleteOrg; + + PROCEDURE run (ip_op VARCHAR2, + ip_hrc_code NUMBER, + ip_org_id NUMBER, + ip_org_short_name VARCHAR2, + ip_org_long_name VARCHAR2) + IS + BEGIN + IF (ip_op ='Add')THEN + IF ((ip_hrc_code IS NULL)or (ip_org_id IS NULL)or + (ip_org_short_name IS NULL)or (ip_org_long_name IS NULL))THEN + htp.p('All input fields must be entered for the Add operation.'); + RETURN; + END IF; + insertOrg (ip_hrc_code, + ip_org_id, + ip_org_short_name, + ip_org_long_name); + ELSIF (ip_op ='Modify')THEN + IF ((ip_hrc_code IS NULL)or (ip_org_id IS NULL)or + (ip_org_short_name IS NULL)or (ip_org_long_name IS NULL))THEN + htp.p('All input fields must be entered for the Modify operation.'); + RETURN; + END IF; + updateOrg(ip_org_id, + ip_org_short_name, + ip_org_long_name); + ELSIF (ip_op ='Delete')THEN + IF (ip_org_id IS NULL)THEN + htp.p('Org Id must be entered for the Delete operation.'); + RETURN; + END IF; + deleteOrg(ip_org_id); + END IF; + END run; +END WebAppOrg; +/ + +-- Procedure p_send_email +CREATE OR REPLACE PROCEDURE p_send_email + (p_mailhost VARCHAR2, + p_from_address VARCHAR2, + p_to_address VARCHAR2, + p_message_text VARCHAR2, + p_retcd OUT NUMBER, + p_err_msg OUT VARCHAR2) +IS + mail_conn utl_smtp.connection; +BEGIN + mail_conn :=utl_smtp.open_connection(p_mailhost,25); + utl_smtp.helo(mail_conn,p_mailhost); + utl_smtp.mail(mail_conn,p_from_address); + utl_smtp.rcpt(mail_conn,p_to_address); + utl_smtp.open_data(mail_conn); + utl_smtp.write_data(mail_conn,p_message_text); + utl_smtp.close_data(mail_conn); + utl_smtp.quit(mail_conn); + p_retcd :=0; +EXCEPTION + WHEN OTHERS THEN + p_retcd :=SQLCODE; + p_err_msg :=SQLERRM; +END; +/ + +-- Sample code to execute p_send_email +declare + retcd number; + err_msg varchar2(1000); +begin + p_send_email('mail.compunnel.com', + 'blakshman@compunnel.com', + 'blakshman@compunnel.com', + 'From:'||'Bulusu'||CHR(13)||CHR(10)|| + 'Subject:'||'Message from Bulusu'||CHR(13)||CHR(10)|| + CHR(13)||CHR(10)|| + 'This is a test message.', + retcd, + err_msg); + IF (retcd <>0)THEN + dbms_output.put_line('ERR:'||err_msg); + END IF; +end; +/ diff --git a/Chapter15/Chapter15.txt b/Chapter15/Chapter15.txt new file mode 100644 index 0000000..238ab0b --- /dev/null +++ b/Chapter15/Chapter15.txt @@ -0,0 +1,16 @@ +ALTER SESSION SET PLSQL_COMPILER_FLAGS ='NATIVE'; + +select uo.object_name,uo.object_type,uss.param_value +from user_stored_settings uss,user_objects uo +where uss.object_id =uo.object_id +and uss.param_name ='plsql_compiler_flags' +and uo.object_type in ('PROCEDURE','FUNCTION'); + +CREATE OR REPLACE FUNCTION f_nocopy + (ip_1 IN NUMBER, + op_2 OUT NOCOPY VARCHAR2) +IS +BEGIN + NULL; +END; +/ diff --git a/LICENSE.txt b/LICENSE.txt new file mode 100644 index 0000000..c8d0da3 --- /dev/null +++ b/LICENSE.txt @@ -0,0 +1,27 @@ +Freeware License, some rights reserved + +Copyright (c) 2003 Bulusu Lakshman + +Permission is hereby granted, free of charge, to anyone obtaining a copy +of this software and associated documentation files (the "Software"), +to work with the Software within the limits of freeware distribution and fair use. +This includes the rights to use, copy, and modify the Software for personal use. +Users are also allowed and encouraged to submit corrections and modifications +to the Software for the benefit of other users. + +It is not allowed to reuse, modify, or redistribute the Software for +commercial use in any way, or for a user’s educational materials such as books +or blog articles without prior permission from the copyright holder. + +The above copyright notice and this permission notice need to be included +in all copies or substantial portions of the software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +AUTHORS OR COPYRIGHT HOLDERS OR APRESS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +SOFTWARE. + + diff --git a/README.md b/README.md new file mode 100644 index 0000000..f63c790 --- /dev/null +++ b/README.md @@ -0,0 +1,15 @@ +#Apress Source Code + +This repository accompanies [*Oracle9i PL/SQL*](http://www.apress.com/9781590590492) by Bulusu Lakshman (Apress, 2003). + +![Cover image](9781590590492.jpg) + +Download the files as a zip using the green button, or clone the repository to your machine using Git. + +##Releases + +Release v1.0 corresponds to the code in the published book, without corrections or updates. + +##Contributions + +See the file Contributing.md for more information on how you can contribute to this repository. diff --git a/Readme.txt b/Readme.txt new file mode 100644 index 0000000..4c87b5d --- /dev/null +++ b/Readme.txt @@ -0,0 +1,9 @@ +1. The zip file contains 15 folders named according to the chapters 01 to 15 +and AppendixA. Each folder contains the source code pertaining to the +respective chapter. + +1. Run the script in AppendixA.txt first. Replace the username, password and + database connect string names with the your schema username, password and + database connect string names respectively. +2. Then use the scripts in each individual chapter folder to run the examples. + diff --git a/contributing.md b/contributing.md new file mode 100644 index 0000000..f6005ad --- /dev/null +++ b/contributing.md @@ -0,0 +1,14 @@ +# Contributing to Apress Source Code + +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. + +## How to Contribute + +1. Make sure you have a GitHub account. +2. Fork the repository for the relevant book. +3. Create a new branch on which to make your change, e.g. +`git checkout -b my_code_contribution` +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. +5. Submit a pull request. + +Thank you for your contribution! \ No newline at end of file