Archive for the ‘Oracle’ tag
External Table Access
I left to chance where students would attempt to place their external files in a Linux or Unix implementation. As frequently occurs, they choose a location in their student
user’s home directory. Any attempt to read an external table based on a file in this type of directory fails because it’s not accessible by the Oracle user because the directory within the student
user’s account isn’t reachable. You can’t simply chown
a directory and the files in a directory.
The failure returns the following result:
SELECT COUNT(*) FROM transaction_upload * ERROR AT line 1: ORA-29913: error IN executing ODCIEXTTABLEOPEN callout ORA-29400: data cartridge error error opening FILE /home/student/upload/transaction_upload.LOG |
The reason isn’t readily visible to all, but a virtual directory must reference a physical directory owned by the oracle
user and dba
group. That also means the oracle
user must own all directories from the logical mount point to the physical directory name.
Assuming you’re working in an Oracle Database 11g XE instance, you can create a valid upload
directory by navigating to this directory:
/u01/app/oracle |
Then, issue this command as the root
user to create a new upload
directory:
mkdir upload |
Now you have the following directory:
/u01/app/oracle/upload |
Assuming you’ve created the upload
directory as the root
user, the root
user should issue the following two commands from the /u01/app/oracle
directory:
chown -R oracle:dba upload chmod -R 755 upload |
Having made that change you should now be able to query the external file source, like a *.csv (comma-separated values) file. Hope this helps those trying to use external tables, which I subsequently wrote about for Toad World – External Tables.
SQL Insert from Query
Sometimes my students find new errors that I’ve never seen. One student did that this week by including an ORDER BY
clause in a subquery that feeds an INSERT
statement. It raises an ORA-00907
exception, like:
ORA-00907: missing right parenthesis |
You can’t include a subquery with an ORDER BY
clause because it generates an error. The reason is simple. A subquery can’t perform a sort operation inside a subquery. Here’s a quick demonstration:
DROP TABLE destination; CREATE TABLE destination ( destination_id NUMBER , destination_name VARCHAR2(20)); INSERT INTO destination ( SELECT 1,'Sample1' FROM dual UNION ALL SELECT 2,'Sample2' FROM dual ORDER BY 1 DESC ); |
If you remove the ORDER BY
clause, the statement works without a problem. For example, here’s the working version:
INSERT INTO destination ( SELECT 1,'Sample1' FROM dual UNION ALL SELECT 2,'Sample2' FROM dual ); |
Alternatively, you can include an ORDER BY
clause when you remove the parentheses from around the subquery. This is an example:
INSERT INTO destination SELECT 1,'Sample1' FROM dual UNION ALL SELECT 2,'Sample2' FROM dual ORDER BY 1 DESC; |
I hope this helps anybody who runs into the problem.
Toad Freeware Page
While I posted how to install Toad for MySQL Freeware five years ago, I’m always surprised how few people know about it there and consistently updated and improved. You can download Toad for MySQL Freeware or Toad Freeware for Oracle, SQL Server, Sybase, or IBM DB2 at this web site.
You can also download Toad Data Modeler Freeware Edition. Just two notes, while Toad for Oracle Freeware is an MSI file, Toad for MySQL Freeware is a zip file and limited to only a Windows install.
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.
OUT Parameter Trick
Raja asked a question but unfortunately, I was buried in the final aspects of the write of the new Oracle Database 12c PL/SQL Programming book. He wanted to know how to pass an object type as an OUT
-only mode parameter from a procedure.
That’s a great question, and it’s actually simple once you understand the difference between Oracle object types and other data types. Oracle object types must always be initiated before you use them, which means you must initialize any OUT
-only mode parameters at the top of your execution section, like this:
1 2 3 4 5 6 7 8 9 10 11 12 | CREATE OR REPLACE PROCEDURE reset_troll ( pv_troll OUT TROLL_OBJECT ) IS /* Troll default name. */ lv_troll_name VARCHAR2(20) := 'Bert'; BEGIN /* Initialize the incoming parameter by allocating memory to it. */ pv_troll := troll_object(); /* Set the name to something other than the 'Tom' default value. */ pv_troll.set_troll(lv_troll_name); END reset_troll; / |
Line 7 shows you the trick, initialize the incoming parameter because there isn’t an incoming parameter for an OUT
-only mode parameter. The calling parameter to an OUT
-only mode parameter is only a reference where PL/SQL will copy the internal object reference. While the calling parameter has been initialized, the reference to the call parameter’s object is where the internal object will be copied. The local program must first ensure a new memory location for a new instance of the object type before it can act on or return an object instance to the external reference. More or less, the internal object is copied to the calling object instance’s memory location when the procedure completes its execution.
Here’s the source code for the troll_object
object type and body:
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 | CREATE OR REPLACE TYPE troll_object IS OBJECT ( troll VARCHAR2(20) , CONSTRUCTOR FUNCTION troll_object RETURN SELF AS RESULT , CONSTRUCTOR FUNCTION troll_object ( troll VARCHAR2 ) RETURN SELF AS RESULT , MEMBER FUNCTION get_troll RETURN VARCHAR2 , MEMBER PROCEDURE set_troll (troll VARCHAR2) , MEMBER FUNCTION to_string RETURN VARCHAR2) INSTANTIABLE NOT FINAL; / CREATE OR REPLACE TYPE BODY troll_object IS /* Default no-argument constructor. */ CONSTRUCTOR FUNCTION troll_object RETURN SELF AS RESULT IS troll TROLL_OBJECT := troll_object('Tom'); BEGIN SELF := troll; RETURN; END troll_object; /* Single argument constructor. */ CONSTRUCTOR FUNCTION troll_object (troll VARCHAR2) RETURN SELF AS RESULT IS BEGIN SELF.troll := troll; RETURN; END troll_object; /* A getter function. */ MEMBER FUNCTION get_troll RETURN VARCHAR2 IS BEGIN RETURN SELF.troll; END get_troll; /* A setter procedure. */ MEMBER PROCEDURE set_troll (troll VARCHAR2) IS BEGIN SELF.troll := troll; END set_troll; /* A function that returns the formatted object type's contents. */ MEMBER FUNCTION to_string RETURN VARCHAR2 IS BEGIN RETURN 'Hello '||SELF.troll; END to_string; END; / |
You can test the reset_troll procedure with the following anonymous block:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | /* Enable printing from a PL/SQL block. */ SET SERVEROUTPUT ON SIZE UNLIMITED /* Anonymous testing block. */ DECLARE lv_troll TROLL_OBJECT := troll_object('Bill'); BEGIN dbms_output.put_line('--------------------'); /* Prints 'Hello William' */ dbms_output.put_line(lv_troll.to_string()); dbms_output.put_line('--------------------'); reset_troll(lv_troll); /* Prints 'Hello Bert' */ dbms_output.put_line(lv_troll.to_string()); dbms_output.put_line('--------------------'); END; / |
If you remark out line 7 from the reset_troll procedure, you’d raise the following exception by the call on line 10 because the local object hasn’t been instantiated (given life). It means there’s no memory location allocated for the instantiated (instance of an object type).
-------------------- Hello Bill -------------------- DECLARE * ERROR at line 1: ORA-30625: method dispatch ON NULL SELF argument IS disallowed ORA-06512: at "VIDEO.RESET_TROLL", line 10 ORA-06512: at line 8 |
Hope this helps those trying to solve the same problem.
Provision Oracle 12c PDB
Somebody wants help provisioning a pluggable database (PDB). While it’s a new concept in the Oracle 12c database, I can sympathize with their plight. It wasn’t clear to me when first working with it, and I couldn’t seem to find a quick tutorial on the web. While it’s in the new Oracle 12c PL/SQL Programming Book, that won’t be out until January 2014.
If you’re new to Oracle 12c, which is most of us, then it’s important to understand that PDB is a private data context. Most of it’s data catalog is private and separate from the overall database. Only a small portion of the database catalog is stored in the container database catalog, and new CDB_ administrative views are added to the database. A PDB is a great solution when you’re leveraging the Editioning feature of Oracle 11g database.
You should note the guarantee from page #9 of Oracle’s Oracle Multitenant:
From the point of view of the client connecting via Oracle Net, the PDB is the database. A PDB is fully compatible with a non-CDB. We shall refer to this from now on as the PDB/non-CDB compatibility guarantee. In other words, the installation scheme for an application backend that ran without error against a non-CDB will run, with no change, and without error, in a PDB and will produce the same result.
Here are the steps that work on both Windows, Linux, or Windows:
- The following SQL command lets you create a pluggable database (PDB) with a
video
user assigned to it:
1 2 3 4 5 6 7 | CREATE PLUGGABLE DATABASE videodb ADMIN USER videoadm IDENTIFIED BY Video1 ROLES = (dba) DEFAULT TABLESPACE videots DATAFILE 'C:\APP\ORACLE\ORADATA\ORCL\VIDEO01.DBF' SIZE 500M ONLINE FILE_NAME_CONVERT = ('C:\APP\ORACLE\ORADATA\ORCL\PDBSEED\', 'C:\APP\ORACLE\ORADATA\ORCL\VIDEOPDB\'); |
Don’t try to create the DEFAULT TABLESPACE
before you provision the database. If you do, you’ll get the following exception:
CREATE PLUGGABLE DATABASE videodb * ERROR at line 1: ORA-00604: error occurred at recursive SQL level 1 ORA-01537: cannot add file 'C:\APP\ORACLE\ORADATA\ORCL\VIDEO01.DBF' - file already part of database |
- You need to stop the Oracle listener and modify the
listener.ora
file. Lines 9 through 12 configure aVIDEODB
Oracle SID. After you make the changes, start the Oracle listener.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 | SID_LIST_LISTENER = (SID_LIST = (SID_DESC = (SID_NAME = CLRExtProc) (ORACLE_HOME = C:\app\oracle\product\12.1.0\dbhome_1) (PROGRAM = extproc) (ENVS = "EXTPROC_DLLS=ONLY:C:\app\oracle\product\12.1.0\dbhome_1\bin\oraclr12.dll") ) (SID_DESC = (SID_NAME = VIDEODB) (ORACLE_HOME = C:\app\oracle\product\12.1.0\dbhome_1) ) ) LISTENER = (DESCRIPTION_LIST = (DESCRIPTION = (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521)) (ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1521)) ) ) |
- You also need to add a
VIDEO
TNS alias to thetnsnames.ora
file for theVIDEODB
pluggable database (PDB).
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 | ORACLR_CONNECTION_DATA = (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = IPC)(KEY = EXTPROC1521)) ) (CONNECT_DATA = (SID = CLRExtProc) (PRESENTATION = RO) ) ) ORCL = (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = orcl) ) ) VIDEO = (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = localhost)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = videodb) ) ) |
- You connect as the
SYSDBA
for theVIDEO
pluggable database with the following syntax (not presently an example in the SQL*Plus Guide). After connecting as theSYSDBA
for theVIDEODB
, you’ll be prompted for a password. The required password is theVideo1
password that you used when you set up theVIDEODB
database.
sqlplus sys@VIDEO AS sysdba |
- After authenticating as the
SYSDBA
, you need to start theVIDEODB
pluggable database, like:
SQL> startup Pluggable DATABASE opened. |
You can also start the pluggable database from the generic SYSDBA
account. You only need to change the CONTAINER
context to pluggable database. You can find the status of pluggable databases with the following query:
SQL> COLUMN RESTRICTED FORMAT A10 SQL> SELECT v.name 2 , v.open_mode 3 , NVL(v.restricted, 'n/a') AS restricted 4 , d.status 5 FROM v$PDBs v INNER JOIN dba_pdbs d USING(guid) 6 ORDER BY v.create_scn; |
The generic sample database returns this after restarting the database:
NAME OPEN_MODE RESTRICTED STATUS ------------------------------ ---------- ---------- -------- PDB$SEED READ ONLY NO NORMAL PDBORCL MOUNTED n/a NORMAL |
The following changes the CONTAINER
context, opens the pdborcl
PDB, and creates a traditional Oracle 11g and backward standard user/schema account in the pluggable database.
SQL> ALTER SESSION SET container=pdborcl; SQL> ALTER PLUGGABLE DATABASE pdborcl OPEN; SQL> CREATE USER johnny IDENTIFIED BY johnny; |
Re-query the status of the pluggable databases, and you’ll see:
NAME OPEN_MODE RESTRICTED STATUS ------------------------------ ---------- ---------- -------- PDB$SEED READ ONLY NO NORMAL PDBORCL READ WRITE NO NORMAL |
If you have more than one pluggable database, you can use the following to open them all as the CDB’s SYSDBA
:
SQL> ALTER PLUGGABLE DATABASE ALL OPEN; |
- As Oracle said during the Oracle 11gR2 release, the DBA role no longer grants
UNLIMITED TABLESPACE
. That means you need to grant it as theSYSDBA
for the PDB, like:
GRANT UNLIMITED TABLESPACE TO videoadm; |
- After you’ve done all the prior steps, you can connect with the following as the Administrative
VIDEO
user:
sqlplus videoadm@VIDEO/Video1 |
Although making such a connection is a poor choice, it would be better to make a secure connection like the one below. The problem with the former is that it exposes information at the OS command line that would be visible to other users. Connecting to the Oracle SQL*Plus with the /NOLOG
option prevents disclosure of that information.
C:\Users\mclaughlinm>sqlplus /nolog SQL*Plus: Release 12.1.0.1.0 Production ON Tue Aug 13 01:28:30 2013 Copyright (c) 1982, 2013, Oracle. ALL rights reserved. SQL> CONNECT videoadm@VIDEO/Video1 Connected. SQL> SHOW USER USER IS "VIDEOADM" |
- Once you’re connected as the
SYSDBA
role, you can create standard (pre-Oracle 12c) user/schemas with the old syntax. Below, we create a student account:
SQL> CREATE USER student IDENTIFIED BY student; SQL> GRANT CREATE cluster, CREATE indextype, CREATE operator 2 , CREATE PROCEDURE, CREATE SEQUENCE, CREATE SESSION 3 , CREATE TABLE, CREATE TRIGGER, CREATE TYPE 4 , CREATE VIEW, UNLIMITED TABLESPACE TO student; |
Naturally, you can also add a USER
from the CDB’s SYSDBA
role when in the proper CONTAINER
context.
This has shown you how to provision a pluggable database (PDB). As a side note, you should know that you can only create user-defined common users (at the CDB-level) with a c##
prefix.
An addendum: DBMS_COMPARE
isn’t provisioned automatically, and you need to manually apply it in your ADMIN
user for the PDB. I’ve blogged about it here.