Archive for the ‘Oracle 12c’ Category
Querying an Object Type
I demonstrated a number of SQL approaches to reading object types in Appendix B of the Oracle Database 12c PL/SQL Programming book. For example, the easiest one to construct and return the results from a TO_STRING
member function uses the TREAT
function:
SELECT TREAT(base_t() AS base_t).to_string() AS "Text" FROM dual; |
However, it seems that I could have provided one more. Here’s an example of how you can test the construction of an object type and how you can return its attributes with a query. It’s important to note that there’s a natural problem with this syntax when you increment a sequence inside the object type. The problem is that it double increments the counter for the sequence.
SELECT * FROM TABLE(SELECT CAST(COLLECT(base_t()) AS base_t_tab) FROM dual); |
The syntax for the COLLECT
function requires that you put it inside a SELECT
-list. Then, the CAST
function converts a single instance of the BASE_T
object type to a one element BASE_T_TAB
collection. Finally, the TABLE
function returns a single row from the BASE_T_TAB
collection.
You can find a more complete article covering column substitutability and object types and subtypes on the ToadWorld site. I think it helps clear up how you can effectively write PL/SQL types and subtypes for persistent object type columns.
Finding Direct Indexes
If you’re not using Toad DBA Suite, it’s sometimes hard to find solutions. Somebody wanted to know how to find indexes that aren’t indirect. Indirect indexes are those created for a primary key because a primary key column or set of columns are both not null and uniquely constrained. Likewise, you create a unique index when you can create a unique constraint. You can’t drop a unique index for a primary key without dropping the primary key or unique constraint that indirectly created it.
The following query returns indexes with one or more columns that are created by a CREATE INDEX
statement on a target table. It excludes unique indexes created by a primary key constraint, and it returns the relative position of columns in an index:
COLUMN sequence_name FORMAT A22 HEADING "Sequence Name" COLUMN column_position FORMAT 999 HEADING "Column|Position" COLUMN column_name FORMAT A22 HEADING "Column|Name" SELECT uin.index_name , uic.column_position , uic.column_name FROM user_indexes uin INNER JOIN user_ind_columns uic ON uin.index_name = uic.index_name AND uin.table_name = uic.table_name WHERE uin.table_name = UPPER('&&table_name') AND NOT uin.index_name IN (SELECT constraint_name FROM user_constraints WHERE table_name = UPPER('&&table_name')) ORDER BY uin.index_name , uic.column_position; |
It can be rewritten into a function, which can then drop indexes based on a table name:
CREATE OR REPLACE FUNCTION drop_indexes_on ( pv_table_name VARCHAR2 ) RETURN NUMBER IS /* A return value. */ lv_return NUMBER := 0; /* A query to return only directly created indexes. */ CURSOR find_indexes_on ( cv_table_name VARCHAR2 ) IS SELECT DISTINCT ui.index_name FROM user_indexes ui INNER JOIN user_ind_columns uic ON ui.index_name = uic.index_name AND ui.table_name = uic.table_name WHERE ui.table_name = UPPER(cv_table_name) AND NOT ui.index_name IN (SELECT constraint_name FROM user_constraints WHERE table_name = UPPER(cv_table_name)); /* Declare function autonomous. */ PRAGMA AUTONOMOUS_TRANSACTION; BEGIN /* Drop the indexes on a table. */ FOR i IN find_indexes_on(pv_table_name) LOOP EXECUTE IMMEDIATE 'DROP INDEX '||i.index_name; lv_return := 1; END LOOP; RETURN lv_return; END drop_indexes_on; / |
You can call the drop_on_indexes_on
function like this:
SELECT drop_indexes_on(UPPER('address_lab')) FROM dual; |
Hope this helps those who need to work with dropping indexes.
Check Constraints
Oracle Database 12c introduces a SEARCH_CONDITION_VC
column to the CDB_
, DBA_
, ALL_
, and USER_CONSTRAINTS
views. The SEARCH_CONDITION_VC
column is a VARCHAR2
data type equivalent to the search condition in the LONG
data type SEARCH_CONDITION
column. Unfortunately, Oracle Database 11g and earlier versions requires you to convert the LONG
data type to a VARCHAR2
for the equivalent behavior. This post provides you with a function to help you do that in Oracle Database 11g.
While Oracle Database 12c let’s you check the search condition of a CHECK
constraint, with this query:
SELECT uc.constraint_name AS constraint_name , uc.search_condition_vc AS search_condition FROM user_constraints uc WHERE uc.table_name = UPPER('table_name') AND REGEXP_LIKE(uc.search_condition_vc,'search_key','i'); |
You need the following GET_SEARCH_CONDITION
function to convert the SEARCH_CONDITION
column from a LONG
data type to a VARCHAR2
data type. It uses the DBMS_SQL
package to convert the LONG
data type.
CREATE OR REPLACE FUNCTION get_search_condition ( pv_table_name VARCHAR2 , pv_column_name VARCHAR2 ) RETURN VARCHAR2 AS /* Declare local variables. */ lv_cursor INTEGER := DBMS_SQL.open_cursor; lv_feedback INTEGER; -- Acknowledgement of dynamic execution lv_length INTEGER; -- Length of the input string lv_value_length INTEGER; -- Length of the output string lv_constraint_name VARCHAR2(30); -- Constraint name lv_return VARCHAR2(32767); -- Function output lv_stmt VARCHAR2(2000); -- Dynamic SQL statement lv_long LONG; -- Dynamic LONG data type. lv_string VARCHAR2(32760); -- Maximum length of LONG data type FUNCTION return_length ( pv_table_name VARCHAR2 , pv_column_name VARCHAR2 ) RETURN VARCHAR2 IS /* Declare a target variable, because of the limit of SELECT-INTO. */ lv_long_view LONG; /* Declare a dynamic cursor. */ CURSOR c ( cv_table_name VARCHAR2 , cv_column_name VARCHAR2 ) IS SELECT uc.search_condition FROM user_constraints uc INNER JOIN user_cons_columns ucc ON uc.table_name = ucc.table_name AND uc.constraint_name = ucc.constraint_name WHERE uc.table_name = UPPER(cv_table_name) AND ucc.column_name = UPPER(cv_column_name) AND uc.constraint_type = 'C'; BEGIN /* Open, fetch, and close cursor to capture view text. */ OPEN c (pv_table_name, pv_column_name); FETCH c INTO lv_long_view; CLOSE c; /* Return the output CLOB length value. */ RETURN LENGTH(lv_long_view); END return_length; BEGIN /* Get the length of the CLOB column value. */ lv_length := return_length(pv_table_name, pv_column_name); /* Create dynamic statement. */ lv_stmt := 'SELECT uc.search_condition'||CHR(10) || 'FROM user_constraints uc INNER JOIN user_cons_columns ucc'||CHR(10) || 'ON uc.table_name = ucc.table_name'||CHR(10) || 'AND uc.constraint_name = ucc.constraint_name'||CHR(10) || 'WHERE uc.table_name = UPPER('''||pv_table_name||''')'||CHR(10) || 'AND ucc.column_name = UPPER('''||pv_column_name||''')'||CHR(10) || 'AND uc.constraint_type = ''C'''; /* Parse and define VARCHAR2 and LONG columns. */ DBMS_SQL.parse(lv_cursor, lv_stmt, DBMS_SQL.native); DBMS_SQL.define_column_long(lv_cursor,1); /* Only attempt to process the return value when fetched. */ IF DBMS_SQL.execute_and_fetch(lv_cursor) = 1 THEN DBMS_SQL.column_value_long( lv_cursor , 1 , lv_length , 0 , lv_string , lv_value_length); END IF; /* Check for an open cursor. */ IF DBMS_SQL.is_open(lv_cursor) THEN DBMS_SQL.close_cursor(lv_cursor); END IF; /* Convert the long length string to a maximum size length. */ lv_return := lv_string; RETURN lv_return; END get_search_condition; / |
Then, you can use the following query to view the full search criteria of a CHECK
constraint that matches part of a search string:
COLUMN constraint_name FORMAT A16 COLUMN search_condition FORMAT A30 SELECT uc.constraint_name AS constraint_name , get_search_condition('table_name','column_name') AS search_condition FROM user_constraints uc WHERE REGEXP_LIKE(get_search_condition('table_name','column_name'),'check_constraint_search_string','i') AND uc.constraint_type = 'C'; |
Hope this helps those looking at discovering the full search criteria of a CHECK
constraint.
Hiding a Java Source
The ability to deploy Java inside the Oracle database led somebody to conclude that the source isn’t visible in the data catalog. Then, that person found that they were wrong because the Java source is visible when you use a DDL command to CREATE
, REPLACE
, and COMPILE
the Java source. This post discloses how to find the Java source and how to prevent it from being stored in the data catalog.
You can verify that the Java class and source files exist with the following query:
1 2 3 4 5 6 7 8 | COLUMN object_name FORMAT A20 HEADING "Object Name" COLUMN object_type FORMAT A12 HEADING "Object Type" COLUMN status FORMAT A14 HEADING "Object Status" SELECT object_name , object_type , status FROM user_objects WHERE object_name = 'ReadFile'; |
It displays:
Object Name Object Type Object Status -------------------- ------------ -------------- ReadFile JAVA SOURCE VALID ReadFile JAVA CLASS VALID 2 rows selected. |
Then, you can use the following query to discovery a Java library created by a SQL command:
1 2 3 4 5 6 | COLUMN line FORMAT 9999 HEADING "Line|#" COLUMN text FORMAT A66 HEADING "Text" SELECT line , text FROM user_source WHERE name = 'ReadFile'; |
It displays the following:
Line # Text ------- ------------------------------------------------------------------ 1 // Java library imports. 2 import java.io.File; 3 import java.io.BufferedReader; 4 import java.io.FileNotFoundException; 5 import java.io.IOException; 6 import java.io.FileReader; 7 import java.security.AccessControlException; 8 9 // Class definition. 10 public class ReadFile { 11 // Define class variables. 12 private static File file; 13 private static FileReader inTextFile; 14 private static BufferedReader inTextReader; 15 private static StringBuffer output = new StringBuffer(); 16 private static String outLine, outText; 17 18 // Define readText() method. 19 public static String readText(String fromFile) 20 throws AccessControlException, IOException { 21 // Read file. 22 try { 23 // Initialize File. 24 file = new File(fromFile); 25 26 // Check for valid file. 27 if (file.exists()) { 28 29 // Assign file to a stream. 30 inTextFile = new FileReader(file); 31 inTextReader = new BufferedReader(inTextFile); 32 33 // Read character-by-character. 34 while ((outLine = inTextReader.readLine()) != null) { 35 output.append(outLine + "\n"); } 36 37 // Assing the StringBuffer to a String. 38 outText = Integer.toString(output.toString().length()); 39 40 // Close File. 41 inTextFile.close(); } 42 else { 43 outText = new String("Empty"); }} 44 catch (IOException e) { 45 outText = new String(""); 46 return outText; } 47 return outText; }} 47 rows selected. |
You can eliminate the source by compiling the Java library outside the database. Then, you use the loadjava
utility to load the only the class file into the data catalog. The syntax would be the following command for an importer
user in a video
Pluggable Database (PDB):
loadjava -r -f -o -user importer/importer@video ReadFile.class |
You should know that this syntax is disallowed by the loadjava
utility, notwithstanding it’s found in the Oracle Database 12c documentation:
loadjava -r -f -o -user importer@video/importer ReadFile.class |
You can verify that only the Java class file exists with the following query:
1 2 3 4 5 6 7 8 | COLUMN object_name FORMAT A20 HEADING "Object Name" COLUMN object_type FORMAT A12 HEADING "Object Type" COLUMN status FORMAT A14 HEADING "Object Status" SELECT object_name , object_type , status FROM user_objects WHERE object_name = 'ReadFile'; |
It displays:
Object Name Object Type Object Status -------------------- ------------ -------------- ReadFile JAVA CLASS VALID 1 row selected. |
Hope this helps those who want to hide the Java source files.
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.
Sequence disallows order by
A call to a PRICE_S1
sequence in a query with an ORDER BY
clause is disallowed, which typically occurs in an INSERT
statement. Any attempt raises the following exception:
SELECT price_s1.NEXTVAL AS price_id * ERROR AT line 1: ORA-02287: SEQUENCE NUMBER NOT allowed here |
You need to remove the ORDER BY
clause to eliminate the error.
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.
Free Oracle NoSQL Book
It’s seldom that Oracle makes an effort to give an Oracle Press book away for free, but they’ve done it. You can download the Getting Started with Oracle NoSQL Database book from Oracle Press for free.
Getting Started with Oracle NoSQL Database
- Overview of Oracle NoSQL Database and Big Data
- Introducing Oracle NoSQL Database
- Oracle NoSQL Database Architecture
- Oracle NoSQL Database Installation and Configuration
- Getting Started with Oracle NoSQL Database Development
- Reading and Writing Data
- Advanced Programming Concepts: Avro Schemas and Bindings
- Capacity Planning and Sizing
- Advanced Topics
Just so you know, knowledge of Java and Hadoop are helpful. It’s a short 71 pages but a nice heads up and here’s what you do starter book.
If you’re opening in iBooks on an iPad, make sure you let the whole book download first as a PDF file. You may only get a partial PDF file when you don’t let it download completely to your browser. It isn’t the speediest download, notwithstanding its small size.
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.
Oracle 12c VARCHAR2?
The Oracle Database 12c documentation says you can set the maximum size of a VARCHAR2
to 32,767 bytes. That’s true except when you’re trying to map a large Java string to a VARCHAR2
. It fails when the physical size of the Java string is greater than 4,000 bytes with an ORA-01002
or fetch out of sequence error.
SELECT read_text_file('C:\Data\loader\Hobbit1.txt') * ERROR at line 1: ORA-24345: A Truncation or null fetch error occurred ERROR: ORA-01002: fetch out of sequence |
You need to grant privileges before you can test this code. You can grant privileges by connecting as the SYS
user of a CDB (or non-multitenant database) or as the ADMIN user of a PDB with the AS SYSDBA
clause. Then, you run the following command to grant external file access to the JVM inside Oracle Database 12c:
BEGIN DBMS_JAVA.GRANT_PERMISSION('IMPORTER' ,'SYS:java.io.FilePermission' ,'C:\Data\Loader\Hobbit1.txt' ,'read'); END; / |
The IMPORTER
is a PDB user name, or a non-multitenant database user name. Please note that permissions must be granted on each physical file.
Here’s the code that raises the error when the external file is greater than 4,000 bytes:
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 | CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED "ReadFile" AS // Java library imports. import java.io.File; import java.io.BufferedReader; import java.io.FileNotFoundException; import java.io.IOException; import java.io.FileReader; import java.security.AccessControlException; // Class definition. public class ReadFile { // Define class variables. private static File file; private static FileReader inTextFile; private static BufferedReader inTextReader; private static StringBuffer output = new StringBuffer(); private static String outLine, outText; // Define readText() method. public static String readText(String fromFile) throws AccessControlException, IOException { // Read file. try { // Initialize File. file = new File(fromFile); // Check for valid file. if (file.exists()) { // Assign file to a stream. inTextFile = new FileReader(file); inTextReader = new BufferedReader(inTextFile); // Read character-by-character. while ((outLine = inTextReader.readLine()) != null) { output.append(outLine + "\n"); } // Assing the StringBuffer to a String. outText = output.toString(); // Close File. inTextFile.close(); } else { outText = new String("Empty"); }} catch (IOException e) { outText = new String(""); return outText; } return outText; }} / |
The PL/SQL wrapper should look like this:
1 2 3 4 5 | CREATE OR REPLACE FUNCTION read_text_file (from_file VARCHAR2) RETURN VARCHAR2 IS LANGUAGE JAVA NAME 'ReadFile.readText(java.lang.String) return java.lang.String'; / |
Then, you can query it like so:
SELECT read_text_file('C:\Data\loader\Hobbit1.txt') FROM dual; |
You can avoid the error by returning the Java file size as a CLOB
data type with the following Java source 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 | CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED "ReadFile" AS // Java library imports. import java.io.File; import java.io.BufferedReader; import java.io.FileNotFoundException; import java.io.IOException; import java.io.FileReader; import java.security.AccessControlException; import java.sql.*; import oracle.sql.driver.*; import oracle.sql.*; // Class definition. public class ReadFile { // Define class variables. private static int i; private static File file; private static FileReader inTextFile; private static BufferedReader inTextReader; private static StringBuffer output = new StringBuffer(); private static String outLine, outText; private static CLOB outCLOB; // Define readText() method. public static oracle.sql.CLOB readText(String fromFile) throws AccessControlException, IOException, SQLException { // Read file. try { // Initialize File. file = new File(fromFile); // Check for valid file. if (file.exists()) { // Assign file to a stream. inTextFile = new FileReader(file); inTextReader = new BufferedReader(inTextFile); // Read character-by-character. while ((outLine = inTextReader.readLine()) != null) { output.append(outLine + "\n"); } // Assing the StringBuffer to a String. outText = output.toString(); // Declare an Oracle connection. Connection conn = DriverManager.getConnection("jdbc:default:connection:"); // Transfer the String to CLOB. outCLOB = CLOB.createTemporary((oracle.jdbc.OracleConnectionWrapper) conn, true, CLOB.DURATION_SESSION); i = outCLOB.setString(1,outText); // Close File. inTextFile.close(); } else { i = outCLOB.setString(1,"Empty"); }} catch (IOException e) { i = outCLOB.setString(1,""); return outCLOB; } return outCLOB; }} / |
The wrapper changes to return a CLOB
and map a java.sql.CLOB
as the return type of the Java library. This command works:
1 2 3 4 5 | CREATE OR REPLACE FUNCTION read_clob_file (from_file VARCHAR2) RETURN CLOB IS LANGUAGE JAVA NAME 'ReadFile.readText(java.lang.String) return oracle.sql.CLOB'; / |
You now query the PL/SQL wrapper with this type of effective SQL*Plus command-line command:
COLUMN atext FORMAT A60 HEADING "Text" COLUMN asize FORMAT 99,999 HEADING "Size" SELECT read_clob_file('C:\Data\loader\Hobbit1.txt') AS AText , LENGTH(read_clob_file('C:\Data\loader\Hobbit1.txt')) AS ASize FROM dual; |
As always, I hope this helps somebody.