Archive for the ‘Oracle 11g’ Category
Parsing DBMS_OUTPUT
Testing with DBMS_OUTPUT.PUT_LINE
is always a bit of a problem when you have strings longer than 80 characters in length, which occurs more frequently with Oracle Database 12c. An example of managing output occurs when you want to print a string with embedded line breaks. My solution is the following parse_rows
procedure:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 | CREATE OR REPLACE PROCEDURE parse_rows ( pv_text VARCHAR2 ) IS /* Declare parsing indexes. */ lv_start NUMBER := 1; lv_end NUMBER := 1; lv_length NUMBER; BEGIN /* Assign an end value based on parsing line return or length. */ IF INSTR(pv_text,CHR(10),lv_start) = 0 THEN lv_end := LENGTH(pv_text) + 1; ELSE lv_end := INSTR(pv_text,CHR(10),lv_start); END IF; /* Assign a length value to the parsed string. */ lv_length := lv_end - lv_start; /* Print first line. */ DBMS_OUTPUT.put_line(SUBSTR(pv_text,lv_start,lv_length)); /* Print the rows of a multiple line string. */ WHILE (lv_end < LENGTH(pv_text)) LOOP /* Assign a new start value. */ lv_start := lv_end + 1; /* Assign a new end value. */ IF INSTR(pv_text,CHR(10),lv_start + 1) = 0 THEN lv_end := LENGTH(pv_text) + 1; ELSE lv_end := INSTR(pv_text,CHR(10),lv_start + 1); END IF; /* Assign a new length. */ lv_length := lv_end - lv_start; /* Print the individual rows. */ DBMS_OUTPUT.put_line(SUBSTR(pv_text,lv_start,lv_length)); END LOOP; END; / |
Here’s the example of a test program for the procedure:
1 2 3 4 5 6 7 | DECLARE /* Declare text. */ lv_text VARCHAR2(200) := 'This is too much'||CHR(10)||'information'||CHR(10)||'on one line.'; BEGIN parse_rows(lv_text); END; / |
It prints the following:
1 2 3 | This is too much information on one line. |
Hope this benefits those looking for quick solution.
Best UTL_FILE Practice
In a post a couple days ago, I promised to provide a best practice approach to reading external files with the UTL_FILE
package. My first assumption is that you’re reading unstructured data because structured data is best read by external tables because external tables can read data much faster with the PARALLEL
option.
My second assumption is that you’re you don’t know how to use or choose not to use the DBMS_LOB
package; specifically, the loadclobfromfile
and loadblobfromfile
procedures. By the way, Chapter 10 of the Oracle Database 12c PL/SQL Programming has several complete examples using the DBMS_LOB
package. My third assumption is that you’d like the external file packaged as a whole, which means you want it returned as a CLOB
or BLOB
data type.
Here’s a generic function that achieves that and avoids the nonsense with closing the file in the exception handler, or worse yet, wrapping it in another PL/SQL schema-level function:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 | CREATE OR REPLACE FUNCTION read_file_to_clob ( pv_location VARCHAR2 , pv_file_name VARCHAR2 ) RETURN CLOB IS /* Declare local input variables. */ lv_location VARCHAR2(60); lv_file_name VARCHAR2(40); /* Declare a file reference pointer and buffer. */ lv_file UTL_FILE.FILE_TYPE; -- File reference lv_line VARCHAR2(32767); -- Reading buffer /* Declare local sizing variables. */ lv_file_size NUMBER; lv_line_size NUMBER; lv_read_size NUMBER :=0; /* Declare local file attribute data. */ lv_file_exists BOOLEAN := FALSE; lv_block_size BINARY_INTEGER; /* Declare a control variable and return CLOB variable. */ lv_enable BOOLEAN := FALSE; lv_return CLOB; BEGIN /* Declare local input variables. */ lv_location := pv_location; lv_file_name := pv_file_name; /* Check for open file and close when open. */ IF UTL_FILE.is_open(lv_file) THEN UTL_FILE.fclose(lv_file); END IF; /* Read the file attributes to get the physical size. */ UTL_FILE.fgetattr( location => lv_location , filename => lv_file_name , fexists => lv_file_exists , file_length => lv_file_size , block_size => lv_block_size ); /* Open only files that exist. */ IF lv_file_exists THEN /* Create a temporary CLOB in memory. */ DBMS_LOB.createtemporary(lv_return, FALSE, DBMS_LOB.CALL); /* Open the file for read-only of 32,767 byte lines. */ lv_file := UTL_FILE.fopen( location => lv_location , filename => lv_file_name , open_mode => 'R' , max_linesize => 32767); /* Read all lines of a text file. */ WHILE (lv_read_size < lv_file_size) LOOP /* Read a line of text until the eof marker. */ UTL_FILE.get_line( file => lv_file , buffer => lv_line ); /* Add the line terminator or 2 bytes to its length. */ lv_line := NVL(lv_line,'')||CHR(10); lv_read_size := lv_read_size + LENGTH(NVL(lv_line,CHR(10))) + 2; /* Write to an empty CLOB or append to an existing CLOB. */ IF NOT lv_enable THEN /* Write to the temporary CLOB variable. */ DBMS_LOB.WRITE( lv_return, LENGTH(lv_line), 1, lv_line); /* Set the control variable. */ lv_enable := TRUE; ELSE /* Append to the temporary CLOB variable. */ DBMS_LOB.writeappend( lv_return, LENGTH(lv_line),lv_line); END IF; END LOOP; /* Close the file. */ UTL_FILE.fclose(lv_file); END IF; /* This line is never reached. */ RETURN lv_return; EXCEPTION WHEN OTHERS THEN UTL_FILE.fclose(lv_file); RAISE NO_DATA_FOUND; END; / |
You can test the function with the following:
SET LONG 100000 SET PAGESIZE 999 SELECT read_file_to_clob('SomeVirtualDirectory','TextFile.txt') AS "Output" FROM dual; |
If anybody has suggestions for improvements, please pass them along. As always, I hope this helps other developers.
Using UTL_FILE Package
Sometimes I’m surprised. Today, the surprise came when somebody pointed to a potential error in another author’s book. The person who asked the question had to send me a screen shot before I believed it.
The author’s code encounters the following error because the code was designed to loop through a multiple line file, and the code called the UTL_FILE.FOPEN
procedure with three instead of four parameters. While it works with only three parameters when the strings are less than or equal to 1,024 (thanks Gary), it throws read errors when a string exceeds the default. You use the fourth parameter when your string exceeds the default length of 1,024.
DECLARE * ERROR AT line 1: ORA-29284: FILE read error ORA-06512: AT "SYS.UTL_FILE", line 106 ORA-06512: AT "SYS.UTL_FILE", line 746 ORA-06512: AT line 26 |
As mentioned, you fix the problem by using the fourth parameter like the call on lines 15 through 18 below:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 | DECLARE /* Declare local input variables. */ lv_location VARCHAR2(60) := 'C:\Data\Direct'; lv_file_name VARCHAR2(40) := 'TextFile.txt'; /* Declare a file reference pointer and buffer. */ lv_file UTL_FILE.FILE_TYPE; -- File reference lv_line VARCHAR2(32767); -- Reading buffer BEGIN /* Check for open file and close when open. */ IF UTL_FILE.is_open(lv_file) THEN UTL_FILE.fclose(lv_file); END IF; /* Open the file for read-only of 32,767 lines of text. The fourth parameter is required when you want to use the GET_LINE procedure to read a file line-by-line. */ lv_file := UTL_FILE.fopen( location => lv_location , filename => lv_file_name , open_mode => 'R' , max_linesize => 32767); /* Read all lines of a text file. */ LOOP /* Read a line of text, when the eof marker is found the get_line procedure raises a NO_DATA_FOUND error, which is why there's no explicit loop. */ UTL_FILE.get_line( file => lv_file , buffer => lv_line ); /* Print the line of text or a line return because UTL_FILE doesn't read line returns. */ DBMS_OUTPUT.put_line(NVL(lv_line,CHR(10))); END LOOP; EXCEPTION WHEN NO_DATA_FOUND THEN UTL_FILE.fclose(lv_file); END; / |
While the foregoing is traditional and uses a physical directory path from the local server’s operating system, you can use a virtual directory from Oracle Database 10g forward. This physical directory is also defined in the utl_file_dir
parameter of the database server. A virtual directory hides the physical directory from the application software, which simplifies physical file maintenance when you need to move the files.
3 | lv_location VARCHAR2(60) := 'DirectVirtualDirectory'; |
The preceding example works, and I’ll put one out converting the external to CLOB
later in the week.
DBMS_JAVA Privilege Error?
It’s possible to get an error after granting privileges to an external file system. One of those errors is tedious to resolve until you understand the rules governing Java NIO file permissions.
You grant privileges to external file systems as the sys
user with the grant_permission
procedure of the dbms_java
package, like
SQL> BEGIN 2 DBMS_JAVA.GRANT_PERMISSION('IMPORTER' 3 ,'SYS:java.io.FilePermission' 4 ,'C:\Data\Upload' 5 ,'read'); 6 END; 7 / |
After you grant privileges to read, write, and delete files with Oracle’s dbms_java
package, you must disconnect any active session to enjoy the new privileges. If you forget to disconnect and re-connect an active session, you get the following error message:
FROM TABLE(list_files(get_directory_path('STAGE'))) * ERROR AT line 2: ORA-29532: JAVA CALL terminated BY uncaught JAVA EXCEPTION: JAVA.security.AccessControlException: DIRECTORY permissions restricted. |
The problem and fix are simple. The permissions aren’t in effect until after you disconnect and reconnect your active sessions. I put this there because when I Google’d it, there wasn’t an answer already.
While I’m on the topic of privilege errors, that aren’t really errors, I thought it would be helpful to qualify how the delete permission works because I couldn’t find it anywhere in the Oracle documentation (if somebody finds it let make a comment that enriches the discussion). Unlike the read and write permissions, the delete permission requires permissions on specific files.
If you only grant permission on like:
SQL> BEGIN 2 DBMS_JAVA.GRANT_PERMISSION('IMPORTER' 3 ,'SYS:java.io.FilePermission' 4 ,'C:\Data\Upload' 5 ,'read,write,delete'); 6 END; 7 / |
You would get this message when trying to delete an external file:
BEGIN * ERROR AT line 1: ORA-29532: JAVA CALL terminated BY uncaught JAVA EXCEPTION: JAVA.security.AccessControlException: the Permission (JAVA.io.FilePermission c:\data\LOG\item_import.LOG read) has NOT been granted TO IMPORTER. The PL/SQL TO GRANT this IS dbms_java.grant_permission( 'IMPORTER', 'SYS:java.io.FilePermission', 'c:\data\log\item_import.log', 'read' ) ORA-06512: AT "IMPORTER.DELETE_FILE", line 1 ORA-06512: AT line 2 |
It requires that you grant permissions on individual files to have the privilege of deleting them from within Oracle. That grant would look like the following:
SQL> BEGIN 2 DBMS_JAVA.GRANT_PERMISSION('IMPORTER' 3 ,'SYS:java.io.FilePermission' 4 ,'C:\Data\Upload\item_import.log' 5 ,'read,write,delete'); 6 END; 7 / |
As always, I hope this helps other developers.
Hidden DBMS_JAVA Nuance
It always happens when I’m in a hurry. Yes, I ran into one of those pesky little features with Oracle’s DBMS_JAVA
package. While I try to write entries with proper GeSHi case semantics, like everyone else I tend to write PL/SQL initially in lowercase. That led me to the discovery of this wonderful error message:
BEGIN * ERROR at line 1: ORA-29532: Java CALL TERMINATED BY uncaught Java exception: oracle.aurora.vm.IdNotFoundException: importer : USER OR ROLE id does NOT exist ORA-06512: at "SYS.DBMS_JAVA", line 705 ORA-06512: at line 2 |
The problem was simple, while not published, you must enter the user/schema name in uppercase text when calling DBMS_JAVA.GRANT_PERMISSION
procedure. Here’s a proper example:
SQL> BEGIN 2 DBMS_JAVA.GRANT_PERMISSION('IMPORTER' 3 ,'SYS:java.io.FilePermission' 4 ,'C:\Data\Upload' 5 ,'read'); 6 END; 7 / |
If you change the IMPORTER
string to lower or mixed case, you raise the aforementioned error. Quite an interesting tidbit that I missed from Oracle Database 10g until Oracle Database 12c. Hope this helps you avoid wondering what’s happening when your line 2 looks like this:
2 DBMS_JAVA.GRANT_PERMISSION('Importer' |
As always, I hope this helps others. If you like more on writing Java inside the Oracle database you can check this older post.
Find Type Dependents
Somebody thought it was nice to show how to drop object type dependents in Oracle Database 11g, but they thought I should show how you discover dependent object types first. More or less, they were concerned how they discover type dependents when they raise the following error:
DROP TYPE item_object * ERROR at line 1: ORA-02303: cannot DROP OR REPLACE a TYPE WITH TYPE OR TABLE dependents |
They had a great point, so here I’m providing and object table function (object table functions are covered in Chapter 8 of Oracle Database 12c PL/SQL Programming book) that displays an object dependency tree.
Unlike table functions in Microsoft SQL Server or PostgreSQL, Oracle requires that you create the object type before you can return a result set table from a parameter-driven function. Here’s the object type for this object table function:
1 2 3 4 5 6 7 8 9 10 11 | -- Create an object type that mimics a record structure. CREATE OR REPLACE TYPE type_tree IS object ( level_id NUMBER , type_name VARCHAR2(30) , object VARCHAR2(10) , parent_type VARCHAR2(30)); / -- Create a UDT Collection. CREATE OR REPLACE TYPE type_tree_table IS TABLE OF type_tree; / |
Now, you can create the object table function that returns an object type dependent tree. This function uses branching recursion because you need to walk the dependency tree. The cursor against the three types of metadata in the database catalog lets us walk the tree. Each object type, and their dependents may have:
- A dependent object type
- A dependent collection, which uses the object type as a base object type.
- A dependent schema function, which uses the object type as a parameter data type or return data type.
- A dependent schema procedure, which uses the object type as a parameter data type.
- A dependent package, which contains a function or procedure using the object type as a parameter data type, or a function using the object type as a return data type.
Here’s the type_dependent
function that walks the tree and displays the hierarchical results:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 | CREATE OR REPLACE FUNCTION type_dependents ( pv_base_object_type VARCHAR2 , pv_level_id NUMBER DEFAULT 1 , pv_collection TYPE_TREE_TABLE DEFAULT NULL ) RETURN TYPE_TREE_TABLE IS /* Declare a return data type. */ lv_level_id NUMBER; /* Declare item type. */ lv_type_name VARCHAR2(30); lv_object_type VARCHAR2(30); lv_parent_type VARCHAR2(30); /* Declare a collection variable. */ lv_collection TYPE_TREE_TABLE := type_tree_table(); lv_incoming TYPE_TREE_TABLE := type_tree_table(); /* The first part of the cursor finds the dependent type names of complex object types, and the second part of the cursor finds the dependent collection types. Effectively the set operator finds two distinct branches because you may use any base type as an element of a complex object or of a collection. */ CURSOR base_type ( cv_level_id NUMBER , cv_base_type VARCHAR2 ) IS SELECT (cv_level_id) AS level_id , LPAD(' ', 2*(cv_level_id - 1)) || ut.type_name AS type_name , ut.typecode AS object_type , NULL AS parent_type FROM user_types ut WHERE ut.type_name = cv_base_type; CURSOR dependent_type ( cv_level_id NUMBER , cv_base_type VARCHAR2 ) IS SELECT cv_level_id AS level_id , LPAD(' ', 2*(cv_level_id - 1)) || uta.type_name AS type_name , ut.typecode AS object_type , ut.type_name AS parent_type FROM user_type_attrs uta INNER JOIN user_types ut ON uta.attr_type_name = ut.type_name WHERE ut.type_name = cv_base_type UNION ALL SELECT cv_level_id AS level_id , LPAD(' ', 2*(cv_level_id - 1)) || uct.type_name AS type_name , CASE WHEN uct.coll_type = 'TABLE' THEN uct.coll_type ELSE 'VARRAY' END AS object_type , ut.type_name AS parent_type FROM user_types ut INNER JOIN user_coll_types uct ON ut.type_name = uct.elem_type_name WHERE uct.elem_type_name = cv_base_type UNION ALL SELECT cv_level_id AS level_id , CASE WHEN package_name IS NULL THEN LPAD(' ', 2*(cv_level_id - 1)) || ua.object_name ELSE LPAD(' ', 2*(cv_level_id - 1)) || ua.package_name END AS type_name , CASE WHEN package_name IS NULL THEN uo.object_type ELSE 'PACKAGE' END AS object_type , ua.type_name AS parent_type FROM user_arguments ua LEFT JOIN user_objects uo ON ua.package_name = uo.object_name OR ua.object_name = uo.object_name WHERE type_name = cv_base_type ORDER BY object_type; BEGIN /* Set the call level indicator. */ lv_level_id := pv_level_id; /* Check if the collection holds values, which should occur in recursive calls. */ IF pv_collection IS NOT NULL THEN lv_collection := pv_collection; ELSE /* Open the base type and record level 1. */ OPEN base_type (lv_level_id, pv_base_object_type); FETCH base_type INTO lv_level_id , lv_type_name , lv_object_type , lv_parent_type; CLOSE base_type; /* Extend the collection. */ lv_collection.EXTEND; lv_collection(lv_collection.COUNT) := type_tree( lv_level_id , lv_type_name , lv_object_type , lv_parent_type ); /* Increment the type dependency level. */ lv_level_id := lv_level_id + 1; END IF; /* Loop through and return records. */ FOR i IN dependent_type(lv_level_id, pv_base_object_type) LOOP /* Extend the collection. */ lv_collection.EXTEND; lv_collection(lv_collection.COUNT) := type_tree( i.level_id , i.type_name , i.object_type , i.parent_type ); /* Recursively call down to dependent types. */ IF i.type_name <> i.parent_type THEN lv_collection := type_dependents(TRIM(i.type_name), (lv_level_id + 1), lv_collection); END IF; END LOOP; /* Return 0 for false. */ RETURN lv_collection; END; / |
You would query the function with the TABLE function, like this:
COLUMN level_id FORMAT 99999 HEADING "Level|ID #" COLUMN type_name FORMAT A30 HEADING "Type Name" COLUMN object FORMAT A10 HEADING "Object Type" COLUMN parent_type FORMAT A30 HEADING "Parent Type" SELECT * FROM TABLE(type_dependents('ITEM_OBJECT',1)); |
It displays the following results based on the sample types created by the original blog post:
Level ID # Type Name Object Typ Parent Type ------ ------------------------------ ---------- ------------------------ 1 ITEM_OBJECT OBJECT 2 GET_ITEM_OBJECT FUNCTION ITEM_OBJECT 2 IDENTIFIED_OBJECT OBJECT ITEM_OBJECT 2 ITEM_PACKAGE PACKAGE ITEM_OBJECT 2 ITEM_TABLE TABLE ITEM_OBJECT 3 ITEM_ASYNC_TABLE COLLECTION ITEM_TABLE 4 ITEM_LIST TABLE ITEM_ASYNC_TABLE 2 ITEM_VARRAY VARRAY ITEM_OBJECT 3 ITEM_ASYNC_VARRAY COLLECTION ITEM_VARRAY 4 ITEM_ARRAY VARRAY ITEM_ASYNC_VARRAY 10 rows selected. |
I hope this helps those working with Oracle Database 10g (de-supported), 11g, or 12c. As a note, you don’t need to drop type dependents in Oracle 12c because it supports type evolution. I cover type evolution in Appendix B of Oracle Database 12c PL/SQL Programming. As always, I hope this helps those trying to determine type dependents in an Oracle database.
Add User Defined Types
Somebody asked me if there was a cheaper alternative to using the Embarcadero Data Architect (a data modeling tool). I said sure, you can use the MySQL Workbench. My friend laughed and said, it’s to model Oracle databases and they use different data types. I broke the news to him that he can create his own user defined types and use MySQL Workbench to model problems for the Oracle Database 11g.
For example, you can launch the MySQL Workbench, and click on the Model menu option, and in the menu window click on the User Defined Types choice, as shown in the following:
Choosing the User Defined Type option, launches the following form. You can enter customized user defined types in the User Defined Types module:
You enter user defined types by entering a name value and choosing valid MySQL type value before clicking the Add button. When you’ve added your last user defined type, click the OK button instead of the Add button. The next screen shot shows how you can create Oracle Database 11g native data types, specifically the NUMBER
and VARCHAR2
data types.
Hopefully, this has shown that you can create User Defined Types let you use MySQL Workbench to create Oracle ERD models. Here’s an example of a table with Oracle’s NUMBER
and VARCHAR2
data types:
Yes, MySQL Workbench is a marvelous tool with wide potential for use to solve problems with MySQL and other databases.
Drop Types Recursively
As covered in my new Oracle Database 12c PL/SQL Programming book (publisher’s satisfied), you can evolve object types. That means you can change a base object type and the change cascades through dependents. Somebody asked how to remove an object type chain without appending the FORCE
clause.
It’s quite easy if you understand writing a recursive function in PL/SQL, as done here:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 | -- Create a recursive function. CREATE OR REPLACE FUNCTION drop_dependents (pv_base_object_type VARCHAR2) RETURN NUMBER IS /* Declare a return data type. */ lv_retval NUMBER := 0; /* Declare item type. */ lv_type_name VARCHAR2(30); lv_object_name VARCHAR2(30); /* The first part of the cursor finds the dependent type names of complex object types, and the second part of the cursor finds the dependent collection types. Effectively the set operator finds two distinct branches because you may use any base type as an element of a complex object or of a collection. */ CURSOR base_type (cv_base_type VARCHAR2) IS SELECT uta.type_name , NULL AS object_name FROM user_type_attrs uta INNER JOIN user_types ut ON uta.attr_type_name = ut.type_name WHERE ut.type_name = cv_base_type UNION ALL SELECT uct.type_name , NULL AS object_name FROM user_types ut INNER JOIN user_coll_types uct ON ut.type_name = uct.elem_type_name WHERE uct.elem_type_name = cv_base_type UNION ALL SELECT CASE WHEN package_name IS NULL THEN uo.object_type ELSE 'PACKAGE' END AS type_name , CASE WHEN package_name IS NULL THEN ua.object_name ELSE ua.package_name END AS object_name FROM user_arguments ua LEFT JOIN user_objects uo ON ua.package_name = uo.object_name OR ua.object_name = uo.object_name WHERE type_name = cv_base_type; BEGIN /* Open a parameterized cursor. */ OPEN base_type(pv_base_object_type); /* Loop through return records. */ LOOP /* Fetch records. */ FETCH base_type INTO lv_type_name , lv_object_name; /* Drop type without dependents, or drop leaf node dependent. */ IF base_type%NOTFOUND THEN /* Drop functions when they include an object type or object type dependent as a formal parameter type or return type. Drop procedures when they include an object type or object type dependent. Drop procedures when any function or procedure uses an object type or object type dependent. */ IF lv_type_name IN ('FUNCTION','PACKAGE','PROCEDURE') THEN /* Drop the base type when no dependents are found. */ EXECUTE IMMEDIATE 'DROP '||lv_type_name||' '||lv_object_name; ELSE /* Drop the base type when no dependents are found. */ EXECUTE IMMEDIATE 'DROP TYPE '||pv_base_object_type; END IF; /* Set exit state to one or true. */ lv_retval := 1; /* Exit the loop. */ EXIT; ELSE /* A type must exclude function, package, and procedure; and the object name must be null before you recurse to another level. */ IF lv_type_name NOT IN ('FUNCTION','PACKAGE','PROCEDURE') AND lv_object_name IS NOT NULL THEN /* Drop base type when no dependents are found. */ lv_retval := drop_dependents(lv_type_name); END IF; END IF; END LOOP; /* Close open cursor. */ CLOSE base_type; /* Return 0 for false. */ RETURN lv_retval; END; / |
Somebody asked me to provide a test case of a hierarchy of object types to support the drop_dependents
function. So, here’s the test case code:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 | -- Create object type. CREATE OR REPLACE TYPE item_object IS OBJECT ( item_name VARCHAR2(30) , item_subname VARCHAR2(30)); / -- Create object type. CREATE OR REPLACE TYPE identified_object IS OBJECT ( identified_id NUMBER , identified_object item_object); / -- Create object collection. CREATE OR REPLACE TYPE item_table IS TABLE OF item_object; / -- Create object collection. CREATE OR REPLACE TYPE item_varray IS VARRAY(5) OF item_object; / -- Create object type. CREATE OR REPLACE TYPE item_async_table IS OBJECT ( item_name VARCHAR2(30) , item_collection item_table); / -- Create object type. CREATE OR REPLACE TYPE item_async_varray IS OBJECT ( item_name VARCHAR2(30) , item_collection item_varray); / -- Create object collection. CREATE OR REPLACE TYPE item_list IS TABLE OF item_async_table; / -- Create object collection. CREATE OR REPLACE TYPE item_array IS VARRAY(10) OF item_async_varray; / -- Create package specification. CREATE OR REPLACE PACKAGE item_package AS /* A published function of the package. */ FUNCTION initialize_object ( id NUMBER , name NUMBER ) RETURN ITEM_OBJECT; END item_package; / -- Create a schema function. CREATE OR REPLACE FUNCTION get_item_object ( pv_id NUMBER , pv_name NUMBER ) RETURN ITEM_OBJECT IS /* Declare a local variable. */ lv_item_object ITEM_OBJECT; BEGIN /* Initialize the object type. */ lv_item_object := item_object(pv_id, pv_name); /* Return the dat type. */ RETURN lv_item_object; END; / |
If you call the function with the base type, it’ll drop the most dependent object type first, and the base object type last. The rest are dropped in their order of dependency. You can call a drop_dependents
function with a base type, like ITEM_OBJECT
, by using the following syntax:
1 2 3 4 5 6 7 | SET SERVEROUTPUT ON SIZE UNLIMITED BEGIN IF drop_dependents('ITEM_OBJECT') = 1 THEN dbms_output.put_line('Objects dropped.'); END IF; END; / |
Hope this helps those looking to drop a chain of object types in an Oracle database.
Mac Mini to the rescue
In teaching, I had a problem because my students have different base operating systems, like Windows 7, Windows 8, Linux, and Mac OS X. I needed a teaching and lecture platform that would let me teach it all (not to mention support their environments). That meant it had to virtualize any of the following with a portable device:
- Windows 7 or 8 hosting natively an Oracle Database 11g XE, 11g, or 12c and MySQL Database 5.6
- Windows 7 or 8 hosting a Fedora or Oracle Unbreakable Linux VM (3 or 4 GB) with Oracle Database 11g XE, 11g, or 12c and MySQL Database 5.6
- Mac OS X hosting a Fedora or Oracle Unbreakable Linux VM (3 or 4 GB) with Oracle Database 11g XE, 11g, or 12c and MySQL Database 5.6
- Ubuntu hosting a Fedora or Oracle Unbreakable Linux VM (3 or 4 GB) with Oracle Database 11g XE, 11g, or 12c and MySQL Database 5.6
I never considered a manufacturer other than Apple for a laptop since they adopted the Intel chip. Too many of the others sell non-hyperthreaded laptop machines that they market as i5 or i7 64-bit OS machines when they’re not. Some of those vendors disable the hyperthreading facility while others provide motherboards that can’t support hyperthreading. The ones I dislike the most provide a BIOS setting that gives the impression you can enable hyperthreading when you can’t. All Apple devices, MacBook, MacBook Pro, Mac Mini, and Mac Pro do fully support a 64-bit OS and their virtualization.
A MacBook Pro came to mind but the disk space requirements were 1 TB, and that’s too pricey. I went with the Mac Mini because with 16 GB of memory and a 1 TB drive it was only $1,200. Add a wireless keyboard and mighty mouse, and an HDMI and mini-DVI connections, and I had my solution. Naturally, my desktop is a one generation old Mac Pro with 64 GB of memory and 12 TB of disk space, which supports all the virtual machines used for testing. Note to Apple marketing staff: The prior version of the Mac Pro let you pay reasonable (3rd party) prices for the additional memory and disk drives.
The Mac Mini means I can travel anywhere and plug into the console and demo tools and techniques from a myriad set of platforms without the hassle of moving on and off to frequently VM images. It’s a great solution with only one downside, HDMI to DVI sometimes creates purple toned screens. It’s unfortunate because some venues have monitors that don’t support HDMI).
Cleaning up a Schema
My students wanted a simple way to cleanup a development schema. So I wrote the following anonymous block PL/SQL program, which also manages the fact that Oracle Database 12c doesn’t completely drop system-generated sequences in active sessions.
The new identity columns in Oracle Database 12c create system-generated sequences, which you must purge from the recycle bin. If you don’t a generic script, like the following raises:
ORA-32794: cannot DROP a system-generated SEQUENCE |
Here’s the script that cleans up an Oracle schema:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 | BEGIN FOR i IN (SELECT object_name , object_type FROM user_objects ORDER BY object_type DESC) LOOP /* Drop types in descending order. */ IF i.object_type = 'TYPE' THEN /* Drop type and force operation because dependencies may exist. Oracle 12c also fails to remove object types with dependents in pluggable databases (at least in release 12.1). Type evolution works in container database schemas. */ EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name||' FORCE'; /* Drop table tables in descending order. */ ELSIF i.object_type = 'TABLE' THEN /* Drop table with cascading constraints to ensure foreign key constraints don't prevent the action. */ EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name||' CASCADE CONSTRAINTS'; /* Oracle 12c ONLY: Purge the recyclebin to dispose of system-generated sequence values because dropping the table doesn't automatically remove them from the active session. CRITICAL: Remark out the following when working in Oracle Database 11g. */ EXECUTE IMMEDIATE 'PURGE RECYCLEBIN'; ELSIF i.object_type = 'LOB' OR i.object_type = 'INDEX' THEN /* A system generated LOB column or INDEX will cause a failure in a generic drop of a table because it is listed in the cursor but removed by the drop of its table. This NULL block ensures there is no attempt to drop an implicit LOB data type or index because the dropping the table takes care of it. */ NULL; ELSE /* Drop any other objects, like sequences, functions, procedures, and packages. */ EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name; END IF; END LOOP; END; / |
As noted by Marat, you can simplify the drop of the tables by simply appending a PURGE
clause to the DROP TABLE
statement.
16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 | /* Drop table tables in descending order. */ ELSIF i.object_type = 'TABLE' THEN /* Drop table with cascading constraints to ensure foreign key constraints but you need to purge system-generated constraints. */ EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name||' CASCADE CONSTRAINTS PURGE'; ELSE /* Drop any other objects, like sequences, functions, procedures, and packages. */ EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name; END IF; END LOOP; END; / |
Don’t run this version if you’ve provisioned an APEX Workspace in the Oracle Schema. I’ve got an updated version of the script for APEX 4.0. As always, I hope this helps a few people.