Archive for the ‘Oracle 11g’ Category
Derived Table Aliases
In my database class, students write solutions as group exercises against the Oracle 11g XE database and then they port the solution individually to the MySQL 5.5 database. One of the students copied over a query like the one below to MySQL (a query used to track the expected number of row returns).
SELECT COUNT(*) FROM (SELECT DISTINCT k.kingdom_id , kki.kingdom_name , kki.population FROM kingdom_knight_import kki LEFT JOIN kingdom k ON kki.kingdom_name = k.kingdom_name AND kki.population = k.population); |
It got an error they didn’t understand:
ERROR 1248 (42000): Every derived TABLE must have its own alias |
Providing a dt
query alias fixes the problem in MySQL for the following query. The fact that it was just an alias was a revelation to the student. That’s because Oracle databases don’t require aliases for inline views (what Oracle calls MySQL derived tables and Microsoft calls a Common Table Expression (CTE)).
SELECT COUNT(*) FROM (SELECT DISTINCT k.kingdom_id , kki.kingdom_name , kki.population FROM kingdom_knight_import kki LEFT JOIN kingdom k ON kki.kingdom_name = k.kingdom_name AND kki.population = k.population) dt; |
MySQL requires that every derived table have its own alias. This make sense when you think about query optimization engines work, but that’s a story for a much longer post.
You can find more about inline views, derived tables, and common table expressions in this older post of mine. This post was promised so that future students can simply google and answer rather than ask me or a class tutor.
Single Wildcard Operator
Somebody wanted to understand why you can backquote a single wildcard operator (that’s the underscore _
character) in MySQL, but can’t in Oracle. The answer is you can in Oracle when you know that you required an additional clause.
While I prefer using regular expression resolution, the LIKE
operator is convenient. Here’s an example of backquoting an underscore in MySQL, where it looks for any string with an underscore anywhere in the string:
SELECT common_lookup_type FROM common_lookup WHERE common_lookup_type LIKE '%\_%'; |
You can gain the same behavior in Oracle by appending the ESCAPE '\'
clause, like this:
SELECT common_lookup_type FROM common_lookup WHERE common_lookup_type LIKE '%\_%' ESCAPE '\'; |
The ESCAPE '\'
clause is one of those Oracle details that often gets lost. It only works when the SQL*Plus ESCAPE
parameter is set to OFF
.
The SQL*Plus ESCAPE
parameter default value is a backslash. and when the ESCAPE parameter is enabled a statement like this raises the following exception:
ERROR at line 3: ORA-01425: escape CHARACTER must be CHARACTER string OF LENGTH 1 |
If you drop the ESCAPE '\'
clause with the ESCAPE
parameter enabled it will return all rows from the table not just those strings with an underscore in the string. Hope this helps if need to look for an underscore in a table.
NDS parameters as IN OUT?
A question posed by a student: “Why are Oracle Native Dynamic SQL (NDS) USING
clause parameters IN
, IN OUT
, or OUT
when the RETURNING INTO
clause manages output values?” It a great question, isn’t it? The followup question was also great, “How do you implement an example of NDS IN OUT
parameters?”
The answer is two fold. First, you should use the USING
clause for parameter list input values and the RETURNING INTO
clause for return values whenever possible. Second, when it’s not possible you’re generally passing parameters into and out of an NDS PL/SQL anonymous block.
The basic prototype for passing and retrieving values from an NDS statement is:
EXECUTE IMMEDIATE sql_stmt USING { IN | IN OUT | OUT } local_variable [, ...] RETURNING INTO { IN OUT | OUT } local_variable [, ...]; |
A quick and hopefully fun example is this parody on Marvel’s The Avengers. The program creates an anonymous block with a super hero of Thor and super villain of Loki, then it uses a USING
clause with IN OUT
parameters to an anonymous block statement. That’s basically the trick to how you use IN OUT
parameters in NDS statements.
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 | -- Enable SERVEROUTPUT. SET SERVEROUTPUT ON SIZE UNLIMITED -- Declare an anonymous testing block. DECLARE -- Declare two local variables. lv_super_hero VARCHAR2(20) := 'Thor'; lv_super_villain VARCHAR2(20) := 'Loki'; -- Declare a null statement variable. lv_stmt VARCHAR2(32767); -- Declare a local procedure to parse the NDS block. PROCEDURE print_code_block (pv_block VARCHAR2) IS -- Declare local parsing variables. lv_length INTEGER := 1; lv_start INTEGER := 1; lv_end INTEGER := 1; BEGIN -- Read line by line on a line return character. WHILE NOT (lv_end = 0) LOOP -- Check for line returns. lv_end := INSTR(lv_stmt,CHR(10),lv_start); -- Check whether line return has been read. IF NOT lv_end = 0 THEN -- Reset the ending substring value and print substring. lv_end := INSTR(lv_stmt,CHR(10),lv_start); dbms_output.put_line('| '||SUBSTR(lv_stmt,lv_start,lv_end - lv_start)); ELSE -- Print the last substring with a semicolon and exit the loop. dbms_output.put_line('| '||SUBSTR(lv_stmt,lv_start,LENGTH(lv_stmt) - lv_start)||';'); END IF; -- Reset the beginning of the string. lv_start := lv_end + 1; END LOOP; END print_code_block; BEGIN -- Demonstrate good triumps over evil. dbms_output.put_line('The good '||lv_super_hero||' beats up the bad '||lv_super_villain||'!'); -- Assign the anonymous block to the local statement variable. lv_stmt := 'DECLARE'||CHR(10) || ' lv_super_hero VARCHAR2(20);'||CHR(10) || ' lv_super_villain VARCHAR2(20);'||CHR(10) || 'BEGIN'||CHR(10) || ' lv_super_hero '||CHR(58)||'= :pv_super_hero;'||CHR(10) || ' lv_super_villain '||CHR(58)||'= :pv_super_villain;'||CHR(10) || ' :pv_super_hero '||CHR(58)||'= lv_super_villain;'||CHR(10) || ' :pv_super_villain '||CHR(58)||'= lv_super_hero;'||CHR(10) || 'END;'; -- Run the NDS program. EXECUTE IMMEDIATE lv_stmt USING IN OUT lv_super_hero , IN OUT lv_super_villain; -- Print the diagnostic code block, that's why it used line returns afterall. dbms_output.put_line('--------------------------------------------------'); print_code_block(lv_stmt); dbms_output.put_line('--------------------------------------------------'); -- Demonstrate the world is upside down without Johnny Depp playing Capt'n Jack. dbms_output.put_line('The good '||lv_super_hero||' beats up the bad '||lv_super_villain||'!'); END; / |
You’ll get the following printed output:
The good Thor beats up the bad Loki! -------------------------------------------------- | DECLARE | lv_super_hero VARCHAR2(20); | lv_super_villain VARCHAR2(20); | BEGIN | lv_super_hero := :pv_super_hero; | lv_super_villain := :pv_super_villain; | :pv_super_hero := lv_super_villain; | :pv_super_villain := lv_super_hero; | END; -------------------------------------------------- The good Loki beats up the bad Thor! |
As always, I hope it helps you understand the concept of the USING
clause with IN OUT
parameters but I hope there’s always better way.
Result Cache Functions
I finally got around to cleaning up old contact me messages. One of the messages raises a question about RESULT_CACHE functions. The writer wanted an example implementing both a standalone schema and package RESULT_CACHE function.
The question references a note from the Oracle Database 11g PL/SQL Programming book (on page 322). More or less, that note points out that at the time of writing a RESULT_CACHE function worked as a standalone function but failed inside a package. When you tried it, you raised the following error message:
PLS-00999: Implementation Restriction (may be temporary) |
It’s no longer true in Oracle 11gR2, but it was true in Oracle 11gR1. I actually mentioned in a blog entry 4 years ago.
You can implement a schema RESULT_CACHE function like this:
1 2 3 4 5 6 7 8 | CREATE OR REPLACE FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE IS BEGIN RETURN pv_first_name || ' ' || pv_last_name; END full_name; / |
You would call it like this from a query:
SELECT full_name(c.first_name, c.last_name) FROM contact c; |
You can declare a published package RESULT_CACHE function like this:
1 2 3 4 5 6 7 | CREATE OR REPLACE PACKAGE cached_function IS FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE; END cached_function; / |
You would implement the function in a package body like this:
1 2 3 4 5 6 7 8 9 10 | CREATE OR REPLACE PACKAGE BODY cached_function IS FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE IS BEGIN RETURN pv_first_name || ' ' || pv_last_name; END full_name; END cached_function; / |
You would call the package function like this from a query:
SELECT cached_function.full_name(c.first_name, c.last_name) FROM contact c; |
I hope this answers the question.
Oracle Within Group
Somebody asked me for a useful example of Oracle 11gR2’s new analytical LISTAGG function that uses a WITHIN GROUP syntax. They’d noticed an update to the askTom that showed how to use it. This post shows how to list values without a displayed aggregation column and how to use a JOIN and GROUP BY clause with the new analytical feature.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 | COLUMN list FORMAT A10 COLUMN last_name FORMAT A10 COLUMN names FORMAT A42 COLUMN members FORMAT 9,990 SELECT m.account_number AS account , c.last_name AS last_name , LISTAGG(c.first_name||DECODE(c.middle_name,NULL,NULL,' '||SUBSTR(c.middle_name,1,1)||'.'),', ') WITHIN GROUP (ORDER BY 2) AS names , COUNT(*) AS members FROM contact c INNER JOIN member m USING (member_id) GROUP BY m.account_number , c.last_name ORDER BY c.last_name; |
It produces the following output:
ACCOUNT LAST_NAME NAMES MEMBERS ---------- ---------- ------------------------------------------ ------- SLC-000021 Jonah Gretelz S. 1 SLC-000020 Moss Jane W. 1 SLC-000023 Nathan Smith B. 1 SLC-000024 Potter Albus S., Ginny, Harry, James S., Lily L. 5 SLC-000022 Royal Jennifer E. 1 SJC-000003 Sweeney Ian M., Matthew, Meaghan 3 SJC-000002 Vizquel Doreen, Oscar 2 SLC-000018 Ward Clinton G. 1 SLC-000019 Ward Brandt H. 1 SJC-000001 Winn Brian, Randi 2 10 rows selected. |
I also found some existing examples you might like, at Oracle-Base, and there they’re showing you how to make it work in prior releases of the database without the new LISTAGG function.
Let’s say you just wanted a concatenated list of users, you could use the following in-line view approach:
1 2 3 4 5 | SELECT list.names FROM (SELECT 'List' AS list , LISTAGG(last_name ||', '||first_name||DECODE(middle_name,NULL,NULL,' '||SUBSTR(middle_name,1,1)||'.'),'; ') WITHIN GROUP (ORDER BY 2) AS names FROM contact) list; |
As always, I hope this helps somebody.
Oracle CSV Imports
The first step in creating an effective import plan for comma-separated value (CSV) files is recognizing your options in a database. There are several options in an Oracle database. You can read the file with Java, C/C++, C#, PL/SQL (through the UTL_FILE package), PHP, Perl, or any other C-callable programming language; or you can use SQL*Loader as a standalone utility or through externally managed tables (known as external tables). The most convenient and non-programming solution is using external tables.
Adopting external tables as your import solution should drive you to consider how to manage the security surrounding this type of methodology. Host hardening is a critical security step because it shuts down most, hopefully all, unauthorized use of the operating system where the database and external files reside. Next, you need to manage the access to the external tables and ensure that exposure of business sensitive information in CSV files is minimized.
This post explains how to manage access and police (cleanup external files) once they’re read into the database. It assumes you have root-level permissions to the operating system and database. The SYS and SYSTEM accounts have the equivalent of root permissions for database configuration. The rule of thumb with these accounts is simple, manage as much as possible with the SYSTEM account before you use the SYS account.
Setting up the Import File System
While you can do all the setup of virtual directories in Oracle regardless of whether you’ve set them up in the operating system, it’s a good idea to set them up in the OS first. The example is using a Windows 7 OS, so you’ll need to change the directories when working in Linux or Unix. Here are the directories:
C:\Imports\ImportFiles C:\Imports\ImportLogs |
You may take note that there are two directories. That’s because you don’t want to grant write privileges to the Oracle virtual directory where you put the files. You can grant read-only privileges to the virtual directory and read-write privileges to the log directory.
Setting up the Import User/Schema
This step lets you create an IMPORT
user/schema in the Oracle database. You need to connect as the SYSTEM user to perform these steps (or another authorized DBA account with adequate privileges):
CREATE USER import IDENTIFIED BY import DEFAULT TABLESPACE users QUOTA 1000M ON users TEMPORARY TABLESPACE temp; |
After creating the user, grant the privileges like this as the SYSTEM user:
GRANT CREATE CLUSTER, CREATE INDEXTYPE, CREATE OPERATOR , CREATE PROCEDURE, CREATE SEQUENCE, CREATE SESSION , CREATE SYNONYM, CREATE TABLE, CREATE TRIGGER , CREATE TYPE, CREATE VIEW TO import; |
Setting up Virtual Directories
A virtual directory in Oracle acts maps an internal database directory name (known as a virtual directory) to a physical directory of the operating system. You create two virtual directories in this example, one holds read-only permissions to the directory where you’re putting the data file, and the other holds read-write permissions to the directory where you’re writing any log files from the external file process.
Log files are generated from this process when you query the data from the external file. Any error in the files conformity is written to a log file.
CREATE DIRECTORY upload_files AS 'C:\Imports\ImportFiles'; CREATE DIRECTORY upload_logs AS 'C:\Imports\ImportLogs'; |
After creating the virtual directories in the database, you must grant appropriate access to the user account that will access the data. This grants those permissions to the IMPORT user:
GRANT READ ON DIRECTORY upload_files TO import; GRANT READ, WRITE ON DIRECTORY upload_logs TO import; |
Setting up an External Table
An external table references both the UPLOAD_FILES and UPLOAD_LOGS virtual directories, and the virtual directories must map to physical directories that allow read and write privileges to the Oracle user. Here’s the external table for this example:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 | CREATE TABLE item_import_ext_table ( asin_number VARCHAR2(10) , item_type VARCHAR2(15) , item_title VARCHAR2(60) , item_subtitle VARCHAR2(60) , item_rating VARCHAR2(8) , item_rating_agency VARCHAR2(4) , item_release_date DATE) ORGANIZATION EXTERNAL ( TYPE oracle_loader DEFAULT DIRECTORY upload_files ACCESS PARAMETERS ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII BADFILE 'UPLOAD_LOGS':'item_import_ext_table.bad' DISCARDFILE 'UPLOAD_LOGS':'item_import_ext_table.dis' LOGFILE 'UPLOAD_LOGS':'item_import_ext_table.log' FIELDS TERMINATED BY ',' OPTIONALLY ENCLOSED BY "'" MISSING FIELD VALUES ARE NULL ) LOCATION ('item_import.csv')) REJECT LIMIT UNLIMITED; |
Setting up a Physical File
You should put the following in a item_import.csv physical file (case sensitivity won’t matter on the Windows 7 platform but will matter on the Linux or Unix platforms):
'B000W74EQC','DVD_WIDE_SCREEN','Harry Potter and the Sorcerer''s Stone',,'PG','MPAA','11-DEC-2007' 'B000W746GK','DVD_WIDE_SCREEN','Harry Potter and the Chamber of Secrets',,'PG','MPAA','11-DEC-2007' 'B000W796OM','DVD_WIDE_SCREEN','Harry Potter and the Prisoner of Azkaban',,'PG','MPAA','11-DEC-2007' 'B000E6EK2Y','DVD_WIDE_SCREEN','Harry Potter and the Goblet of Fire',,'PG-13','MPAA','07-MAR-2006' 'B000W7F5SS','DVD_WIDE_SCREEN','Harry Potter and the Order of the Phoenix',,'PG-13','MPAA','11-DEC-2007' 'B002PMV9FG','DVD_WIDE_SCREEN','Harry Potter and the Half-Blood Prince',,'PG','MPAA','08-DEC-2009' 'B001UV4XHY','DVD_WIDE_SCREEN','Harry Potter and the Deathly Hallows, Part 1',,'PG-13','MPAA','15-APR-2011' 'B001UV4XIS','DVD_WIDE_SCREEN','Harry Potter and the Deathly Hallows, Part 2',,'PG-13','MPAA','11-NOV-2011' |
Testing the External Table
After putting the item_import.csv file in the C:\Imports\ImportFiles directory, you can test the process at this point by running the following query:
SET PAGESIZE 99 COLUMN asin_number FORMAT A11 HEADING "ASIN #" COLUMN item_title FORMAT A46 HEADING "ITEM TITLE" COLUMN item_rating FORMAT A6 HEADING "RATING" COLUMN item_release_date FORMAT A11 HEADING "RELEASE|DATE" SELECT asin_number , item_title , item_rating , TO_CHAR(item_release_date,'DD-MON-YYYY') AS item_release_date FROM item_import_ext_table; |
It should return eight rows.
Extending Access to the Data Dictionary
The physical directory names of virtual directories are hidden from generic users. They’re available in the ALL_DIRECTORIES and DBA_DIRECTORIES administrative view for queries by the SYS, SYSTEM, and any DBA role privileged users.
While a privileged user can query the view, placing the view inside a function or procedure deployed in the privileged user’s schema would raise an ORA-00942 error. That error signals that the table or view does not exist.
This example deploys the view in the SYSTEM schema. That means it requires you make the following grant as the SYS user:
GRANT SELECT ON sys.dba_directories TO system; |
After making the grant from the SYS schema to the SYSTEM schema, connect to the SYSTEM schema. Then, create the following GET_DIRECTORY_PATH 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 | CREATE OR REPLACE FUNCTION get_directory_path ( virtual_directory IN VARCHAR2 ) RETURN VARCHAR2 IS -- Define RETURN variable. directory_path VARCHAR2(256) := ''; --Define dynamic cursor. CURSOR get_directory (virtual_directory VARCHAR2) IS SELECT directory_path FROM sys.dba_directories WHERE directory_name = virtual_directory; -- Define a LOCAL exception FOR name violation. directory_name EXCEPTION; PRAGMA EXCEPTION_INIT(directory_name,-22284); BEGIN OPEN get_directory (virtual_directory); FETCH get_directory INTO directory_path; CLOSE get_directory; -- RETURN file name. RETURN directory_path; EXCEPTION WHEN directory_name THEN RETURN NULL; END get_directory_path; / |
It’s tempting to make the grant on this function to PUBLIC user but that would expose information that any DBA should try and limit. That means you grant EXECUTE privilege only to the IMPORT schema.
This grant should be made as the SYSTEM user:
GRANT EXECUTE ON get_directory_path TO import; |
After granting the EXECUTE privilege to the IMPORT user, connect to the IMPORT schema and create a synonym to the GET_DIRECTORY_PATH function. The syntax for that command is:
CREATE SYNONYM get_directory_path FOR system.get_directory_path; |
You can now test your access to the function with the following query from the IMPORT schema:
SELECT get_directory_path('UPLOAD_FILES') FROM dual; |
You should return the following if you’ve got everything working at this point:
GET_DIRECTORY_PATH('UPLOAD_FILES') ------------------------------------ C:\Imports\ImportFiles |
At this point, you’ve completed the second major configuration component. You now need the ability to read files outside the database, which can be done with Java in Oracle 10g or Oracle 11g (that’s not possible in Oracle 10g XE or Oracle 11g XE because they don’t support an internal JVM). The
Reading Virtual Directory Files
The GET_DIRECTORY_PATH function provides you with the ability to read the Oracle data catalog and find the absolute directory path of a virtual directory. In this framework, you need this value to find whether the item_import.csv physical file is present in the file system before you read the file.
There doesn’t appear to be a neat little function to read an external directory. At least, there’s not one in the UTL_FILE or DBMS_LOB packages where you’d think it should be found. Unfortunately, that leaves us with two alternatives. One is to write an external library in C, C++, or C#. Another is to write an internal Java library that reads the file system. You accomplish this by granting permissions to a target directory or directories.
The first step is to create a scalar array of VARCHAR2 variables, like
CREATE OR REPLACE TYPE file_list AS TABLE OF VARCHAR2(255); / |
The second step is to write the Java library file. You can write it three ways. One accepts default error handling and the others override the default exception handling. If you’re new to Java, you should take the basic library with default handling. If you’ve more experience, you may want to override the helpful message with something that causes the developer to check with the DBA or simply suppress the message to enhance security.
You should note that the database connection is an Oracle Database 11g internal database connection. The connection only does one thing. It allows you to map the ArrayDescriptor to a schema-level SQL collection type. The element types of these collections should be scalar variables, like DATE, NUMBER, or VARCHAR2 data types.
The more advanced method overrides exception handling by suppressing information about the java.properties settings. You can do it by catching the natively thrown exception and re-throw it or ignore it. The example ignores it because handling it in Java reports an unhandled exception at the PL/SQL or SQL layer, which leads end users to think you have a major design problem.
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 | CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED "ListVirtualDirectory" AS // Import required classes. import java.io.*; import java.security.AccessControlException; import java.sql.*; import java.util.Arrays; import oracle.sql.driver.*; import oracle.sql.ArrayDescriptor; import oracle.sql.ARRAY; // Define the class. public class ListVirtualDirectory { // Define the method. public static ARRAY getList(String path) throws SQLException { // DECLARE variable AS a NULL, required because OF try-catch block. ARRAY listed = NULL; // Define a connection (this IS FOR Oracle 11g). Connection conn = DriverManager.getConnection("jdbc:default:connection:"); // USE a try-catch block TO trap a Java permission error ON the directory. try { // DECLARE a class WITH the file list. File directory = NEW File(path); // DECLARE a mapping TO the schema-level SQL collection TYPE. ArrayDescriptor arrayDescriptor = NEW ArrayDescriptor("FILE_LIST",conn); // Translate the Java String[] TO the Oracle SQL collection TYPE. listed = NEW ARRAY(arrayDescriptor,conn,((Object[]) directory.list())); } catch (AccessControlException e) {} RETURN listed; }} / |
You can’t call an internal Java library without a PL/SQL wrapper function. Here’s the wrapper function for this Java library:
CREATE OR REPLACE FUNCTION list_files(path VARCHAR2) RETURN FILE_LIST IS LANGUAGE JAVA NAME 'ListVirtualDirectory.getList(java.lang.String) return oracle.sql.ARRAY'; / |
You MUST grant the Oracle Database’s internal JVM authority to read the external directory before you can return the directory contents. Any attempt to read a directory without the proper permissions raises an ORA-29532 exception.
The following is an anonymous block to grant permissions to a directory. You must grant a minimum of read permissions but since you’ll also delete this file later in the post you should grant read, write, and delete. You must run it from the SYSDBA role as the SYS user.
1 2 3 4 5 6 7 | BEGIN DBMS_JAVA.GRANT_PERMISSION('IMPORT' ,'SYS:java.io.FilePermission' ,'C:\Imports\ImportFiles' ,'read,write,delete'); END; / |
While you’re connected, it’s a good idea to grant the same privileges to your log directory:
1 2 3 4 5 6 7 | BEGIN DBMS_JAVA.GRANT_PERMISSION('IMPORT' ,'SYS:java.io.FilePermission' ,'C:\Imports\ImportLogs' ,'read,write,delete'); END; / |
You should now be able to read the contents of an external file from another PL/SQL block or from a SQL statement. Here’s an example of the SQL statement call that uses everything developed to this point:
SELECT column_value AS "File Names" FROM TABLE(list_files(get_directory_path('UPLOAD_FILES'))); |
It should return the item_import.csv physical file as the only file in the physical directory, like:
File Names ----------------- item_import.csv |
Mapping an External Table to a source File
The next step leverages the user segment of the Oracle Database’s data catalog and all the components developed above to find and display the external table and external file. This query returns the results:
COLUMN TABLE_NAME FORMAT A30 COLUMN file_name FORMAT A30 SELECT xt.table_name , xt.file_name FROM (SELECT uxt.TABLE_NAME , ixt.column_value AS file_name FROM user_external_tables uxt CROSS JOIN TABLE(list_files(get_directory_path(uxt.default_directory_name))) ixt) xt JOIN user_external_locations xl ON xt.table_name = xl.table_name AND xt.file_name = xl.location; |
It should return the following:
TABLE_NAME FILE_NAME ------------------------------ ------------------------------ ITEM_IMPORT_EXT_TABLE item_import.csv |
You can migrate the query into the following function. It returns a zero when the file isn’t found and a one when it is found.
CREATE OR REPLACE FUNCTION external_file_found ( table_in VARCHAR2 ) RETURN NUMBER IS -- Define a default return value. retval NUMBER := 0; -- Decalre a cursor to find external tables. CURSOR c (cv_table VARCHAR2) IS SELECT xt.table_name , xt.file_name FROM (SELECT uxt.TABLE_NAME , ixt.column_value AS file_name FROM user_external_tables uxt CROSS JOIN TABLE(list_files(get_directory_path(uxt.default_directory_name))) ixt) xt JOIN user_external_locations xl ON xt.table_name = xl.table_name AND xt.file_name = xl.location AND xt.table_name = UPPER(cv_table); BEGIN FOR i IN c(table_in) LOOP retval := 1; END LOOP; RETURN retval; END; / |
With the EXTERNAL_FILE_FOUND function, you can create a function that returns rows when the external file is found and no rows when the external file isn’t found. The following view hides the logic required to make that work:
CREATE OR REPLACE VIEW item_import AS SELECT * FROM item_import_ext_table WHERE external_file_found('ITEM_IMPORT_EXT_TABLE') = 1; |
Conveniently, you can now query the ITEM_IMPORT view without the risk of raising the following error when the file is missing:
SELECT * FROM item_import_ext_table * ERROR at line 1: ORA-29913: error IN executing ODCIEXTTABLEOPEN callout ORA-29400: DATA cartridge error KUP-04040: file item_import.csv IN UPLOAD_FILES NOT found |
You can now grant the SELECT privilege on the ITEM_IMPORT view to your application schema, like:
GRANT SELECT ON item_import TO application; |
After granting the SELECT privilege on the ITEM_IMPORT view to the APPLICATION schema, you can create a synonym to hide the IMPORT schema.
CREATE SYNONYM item_import FOR item_import; |
At this point, many developers feel they’re done. Enclosing the results in a schema-level function provides more utility than a view. The next section shows you how to replace the view with a schema-level function.
Replacing the View with an Object Table Function
Inside a schema-level function, you can assign the results from the query to a SQL collection of an object type. The object type should mirror the structure of the table, like the following:
1 2 3 4 5 6 7 8 9 | CREATE OR REPLACE TYPE item_import_object IS OBJECT ( asin_number VARCHAR2(10) , item_type VARCHAR2(15) , item_title VARCHAR2(60) , item_subtitle VARCHAR2(60) , item_rating VARCHAR2(8) , item_rating_agency VARCHAR2(4) , item_release_date DATE); / |
After creating the object type that mirrors the structure of the ITEM_IMPORT_EXT_TABLE table, you need to create a list like collection of the object type. The nested table collection type acts like a list in Oracle:
1 2 3 | CREATE OR REPLACE TYPE item_import_object_table IS TABLE OF item_import_object; / |
After defining the object type and collection, you can access them in the following type of 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 | CREATE OR REPLACE FUNCTION external_file_contents ( table_in VARCHAR2 ) RETURN item_import_object_table IS -- Define a local counter. lv_counter NUMBER := 1; -- Construct an empty collection of ITEM_IMPORT_OBJECT data types. lv_item_import_table ITEM_IMPORT_OBJECT_TABLE := item_import_object_table(); -- Decalre a cursor to find external tables. CURSOR c (cv_table VARCHAR2) IS SELECT * FROM item_import_ext_table WHERE external_file_found(cv_table) = 1; BEGIN FOR i IN c(table_in) LOOP lv_item_import_table.EXTEND; lv_item_import_table(lv_counter) := item_import_object(i.asin_number ,i.item_type ,i.item_title ,i.item_subtitle ,i.item_rating ,i.item_rating_agency ,i.item_release_date); lv_counter := lv_counter + 1; END LOOP; /* * This is where you can place autonomous function calls: * ====================================================== * - These can read source and log files, and write them * to CLOB attributes for later inspection or review. * - These can call Java libraries to delete files, but * you should note that Java deletes any file rather * than moving it to the trash bin (where you might * recover it. */ RETURN lv_item_import_table; END; / |
Between the assignment to the collection and the return statement of the function, you have the ability of calling any number of autonomous functions. Any schema-level function can call autonomous functions that read and write tables with DML statements, like the INSERT, UPDATE, and DELETE statements. You can also call schema-functions that wrap Java libraries that delete external files.
You can confirm that the steps work by running the following query with or without the SQL*Plus formatting:
/* * SQL*Plus formatting. */ SET PAGESIZE 99 COLUMN asin_number FORMAT A11 HEADING "ASIN #" COLUMN item_title FORMAT A46 HEADING "ITEM TITLE" COLUMN item_rating FORMAT A6 HEADING "RATING" COLUMN item_release_date FORMAT A11 HEADING "RELEASE|DATE" /* * Query works only when item_import.csv file is present. */ SELECT asin_number , item_title , item_rating , TO_CHAR(item_release_date,'DD-MON-YYYY') AS item_release_date FROM TABLE(external_file_contents('ITEM_IMPORT_EXT_TABLE')); |
It should return the following from SQL*Plus:
RELEASE ASIN # ITEM TITLE RATING DATE ----------- ---------------------------------------------- ------ ----------- B000W74EQC Harry Potter and the Sorcerer's Stone PG 11-DEC-2007 B000W746GK Harry Potter and the Chamber of Secrets PG 11-DEC-2007 B000W796OM Harry Potter and the Prisoner of Azkaban PG 11-DEC-2007 B000E6EK2Y Harry Potter and the Goblet of Fire PG-13 07-MAR-2006 B000W7F5SS Harry Potter and the Order of the Phoenix PG-13 11-DEC-2007 B002PMV9FG Harry Potter and the Half-Blood Prince PG 08-DEC-2009 B001UV4XHY Harry Potter and the Deathly Hallows, Part 1 PG-13 15-APR-2011 B001UV4XIS Harry Potter and the Deathly Hallows, Part 2 PG-13 11-NOV-2011 |
The creation of the schema-level function lets you recreate the ITEM_IMPORT view. The following view would encapsulate (or hide) the presence of the function, which hides all the infrastructure components developed before this section (see line 14 in the function):
1 2 3 | CREATE OR REPLACE VIEW item_import AS SELECT * FROM TABLE(external_file_contents('ITEM_IMPORT_EXT_TABLE')); |
Implementing a Managed Import Process
During any import the information from the import process is exposed and one or more items may fail during the import process. That means the source file and loading log files must be preserved immediately after reading the data successfully. This is done by loading the data source file and log, discard, and bad import files into database tables. Only the source and log files exist when all rows are well formed, but the log files are reused for any subsequent load and require human inspection to isolate a specific upload.
The best way to implement this requires creating individual tables to hold each of the four potential large objects. The ITEM_MASTER table holds a transactional primary key and a table name for the import table. The primary key of the ITEM_MASTER table is the base key for imports and the ITEM_DATA, ITEM_LOG, ITEM_DISCARD, and ITEM_BAD tables hold foreign keys that point back to the ITEM_MASTER table’s primary key. These tables also hold a character large object column (CLOB), which will hold the respective source data file or log, discard, or bad files.
The following create the tables for the logging framework:
CREATE TABLE import_master ( import_master_id NUMBER CONSTRAINT pk_import_master PRIMARY KEY , import_table VARCHAR2(30)); -- Create sequence for import master. CREATE SEQUENCE import_master_s; -- Create import table. CREATE TABLE import_data ( import_data_id NUMBER CONSTRAINT pk_import_data PRIMARY KEY , import_master_id NUMBER , import_data CLOB , CONSTRAINT fk_import_data FOREIGN KEY (import_data_id) REFERENCES import_master (import_master_id)) LOB (import_data) STORE AS BASICFILE item_import_clob (TABLESPACE users ENABLE STORAGE IN ROW CHUNK 32768 PCTVERSION 10 NOCACHE LOGGING STORAGE (INITIAL 1048576 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645)); -- Create sequence for import master. CREATE SEQUENCE import_data_s; -- Create import table. CREATE TABLE import_log ( import_log_id NUMBER CONSTRAINT pk_import_log PRIMARY KEY , import_master_id NUMBER , import_log CLOB , CONSTRAINT fk_import_log FOREIGN KEY (import_log_id) REFERENCES import_master (import_master_id)) LOB (import_log) STORE AS BASICFILE item_import_log_clob (TABLESPACE users ENABLE STORAGE IN ROW CHUNK 32768 PCTVERSION 10 NOCACHE LOGGING STORAGE (INITIAL 1048576 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645)); -- Create sequence for import master. CREATE SEQUENCE import_log_s; -- Create import table. CREATE TABLE import_discard ( import_discard_id NUMBER CONSTRAINT pk_import_discard PRIMARY KEY , import_master_id NUMBER , import_discard CLOB , CONSTRAINT fk_import_discard FOREIGN KEY (import_discard_id) REFERENCES import_master (import_master_id)) LOB (import_discard) STORE AS BASICFILE item_import_discard_clob (TABLESPACE users ENABLE STORAGE IN ROW CHUNK 32768 PCTVERSION 10 NOCACHE LOGGING STORAGE (INITIAL 1048576 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645)); -- Create sequence for import master. CREATE SEQUENCE import_discard_s; -- Create import table. CREATE TABLE import_bad ( import_bad_id NUMBER CONSTRAINT pk_import_bad PRIMARY KEY , import_master_id NUMBER , import_bad CLOB , CONSTRAINT fk_import_bad FOREIGN KEY (import_bad_id) REFERENCES import_master (import_master_id)) LOB (import_bad) STORE AS BASICFILE item_import_bad_clob (TABLESPACE users ENABLE STORAGE IN ROW CHUNK 32768 PCTVERSION 10 NOCACHE LOGGING STORAGE (INITIAL 1048576 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645)); -- Create sequence for import master. CREATE SEQUENCE import_bad_s; |
The tables set the targets for uploading the source and log files. You should note that the table name is also the column name for the CLOB column, this becomes convenient when supporting a Native Dynamic SQL (NDS) statement in a single autonomous function. The LOAD_CLOB_FROM_FILE function supports reading the external source and log files and writing them their respective tables.
There is a DEADLOCK possibility with this type of architecture. It requires that the base row in the IMPORT_MASTER table is committed before attempting inserts into one of the dependent tables. A call to the function raises an error when the primary key column hasn’t been committed before hand.
You already set the access privileges for the DBMS_LOB package when you granted them to the UPLOAD_FILES and UPLOAD_LOGS virtual directories. This function only requires read permissions, which were granted to both virtual directories.
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 | CREATE OR REPLACE FUNCTION load_clob_from_file ( pv_src_file_name IN VARCHAR2 , pv_virtual_dir IN VARCHAR2 , pv_table_name IN VARCHAR2 , pv_column_name IN VARCHAR2 , pv_foreign_key IN NUMBER ) RETURN NUMBER IS -- Declare placeholder for sequence generated primary key. lv_primary_key NUMBER; -- Declare default return value. lv_retval NUMBER := 0; -- Declare local variables for DBMS_LOB.LOADCLOBFROMFILE procedure. des_clob CLOB; src_clob BFILE := BFILENAME(pv_virtual_dir,pv_src_file_name); des_offset NUMBER := 1; src_offset NUMBER := 1; ctx_lang NUMBER := dbms_lob.default_lang_ctx; warning NUMBER; -- Declare pre-reading size. src_clob_size NUMBER; -- Declare variables for handling NDS sequence value. lv_sequence VARCHAR2(30); lv_sequence_output NUMBER; lv_sequence_tagline VARCHAR2(10) := '_s.nextval'; -- Define local variable for Native Dynamic SQL (NDS) Statement. stmt VARCHAR2(2000); -- Declare the function as an autonomous transaction. PRAGMA AUTONOMOUS_TRANSACTION; BEGIN -- Open file only when found. IF dbms_lob.fileexists(src_clob) = 1 AND NOT dbms_lob.isopen(src_clob) = 1 THEN src_clob_size := dbms_lob.getlength(src_clob); dbms_lob.open(src_clob,dbms_lob.lob_readonly); END IF; -- Concatenate the sequence name with the tagline. lv_sequence := pv_table_name || lv_sequence_tagline; -- Assign the sequence through an anonymous block. stmt := 'BEGIN ' || ' :output := '||lv_sequence||';' || 'END;'; -- Run the statement to extract a sequence value through NDS. EXECUTE IMMEDIATE stmt USING IN OUT lv_sequence_output; -- Create a dynamic statement that works for all source and log files. -- ---------------------------------------------------------------------- -- NOTE: This statement requires that the row holding the primary key -- has been committed because otherwise it raises the following -- error because it can't verify the integrity of the foreign -- key constraint. -- ---------------------------------------------------------------------- -- DECLARE -- * -- ERROR at line 1: -- ORA-00060: deadlock detected while waiting for resource -- ORA-06512: at "IMPORT.LOAD_CLOB_FROM_FILE", line 50 -- ORA-06512: at line 20 -- ---------------------------------------------------------------------- stmt := 'INSERT INTO '||pv_table_name||' '||CHR(10)|| 'VALUES '||CHR(10)|| '('||lv_sequence_output||CHR(10)|| ','||pv_foreign_key||CHR(10)|| ', empty_clob())'||CHR(10)|| 'RETURNING '||pv_column_name||' INTO :locator'; -- Run dynamic statement. EXECUTE IMMEDIATE stmt USING OUT des_clob; -- Read and write file to CLOB, close source file and commit. dbms_lob.loadclobfromfile( dest_lob => des_clob , src_bfile => src_clob , amount => dbms_lob.getlength(src_clob) , dest_offset => des_offset , src_offset => src_offset , bfile_csid => dbms_lob.default_csid , lang_context => ctx_lang , warning => warning ); -- Close open source file. dbms_lob.close(src_clob); -- Commit write and conditionally acknowledge it. IF src_clob_size = dbms_lob.getlength(des_clob) THEN COMMIT; lv_retval := 1; ELSE RAISE dbms_lob.operation_failed; END IF; RETURN lv_retval; END load_clob_from_file; / |
You can test this procedure against the data source file with the following script file:
-- Insert a sample row in the master table. INSERT INTO import_master VALUES (import_master_s.nextval,'ITEM_IMPORT_EXT_TABLE'); -- Record the row value to avoid deadlock on uncommitted master record. COMMIT; -- Test program for loading CLOB files. DECLARE -- Declare testing variables. lv_file_name VARCHAR2(255) := 'item_import.csv'; lv_virtual_dir VARCHAR2(255) := 'UPLOAD_FILES'; lv_table_name VARCHAR2(30) := 'IMPORT_DATA'; lv_column_name VARCHAR2(30) := 'IMPORT_DATA'; lv_foreign_key NUMBER; BEGIN -- Assign the current value of the sequence to a local variable. lv_foreign_key := import_master_s.currval; -- Check if you can read and insert a CLOB column. IF load_clob_from_file(lv_file_name ,lv_virtual_dir ,lv_table_name ,lv_table_name ,lv_foreign_key) = 1 THEN -- Display a successful subordinate routine. dbms_output.put_line('Subordinate routine succeeds.'); ELSE -- Display a failed subordinate routine. dbms_output.put_line('Subordinate routine fails.'); END IF; END load_clob_from_file; / |
You can test this procedure against the log file with the following script file:
DECLARE -- Declare testing variables. lv_file_name VARCHAR2(255) := 'item_import_ext_table.log'; lv_virtual_dir VARCHAR2(255) := 'UPLOAD_LOGS'; lv_table_name VARCHAR2(30) := 'IMPORT_LOG'; lv_column_name VARCHAR2(30) := 'IMPORT_LOG'; lv_foreign_key NUMBER; BEGIN -- Assign the current value of the sequence to a local variable. lv_foreign_key := import_master_s.currval; dbms_output.put_line('Foreign key ['||lv_foreign_key||']'); -- Check if you can read and insert a CLOB column. IF load_clob_from_file(lv_file_name ,lv_virtual_dir ,lv_table_name ,lv_table_name ,lv_foreign_key) = 1 THEN -- Display a successful subordinate routine. dbms_output.put_line('Subordinate routine succeeds.'); ELSE -- Display a failed subordinate routine. dbms_output.put_line('Subordinate routine fails.'); END IF; END; / |
You now have the ability to read and store the source and log files in CLOB columns. The next step is to write a master function that writes the master row and calls the LOAD_CLOB_FROM_FILE function for the source file and each of the log files. That’s what the CLEANUP_EXTERNAL_FILES function provides.
Unfortunately, the Java logic requires using the logical and operation, which is two ampersands (&&). This requires that you turn off substitution variables in SQL*Plus. You do that by disabling DEFINE, like this:
SET DEFINE OFF |
You can compile this Java library file after you’ve disabled LOAD_CLOB_FROM_FILE:
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 cleanup_external_files ( table_in VARCHAR2 , data_directory_in VARCHAR2 , log_directory_in VARCHAR2 ) RETURN NUMBER IS -- Declare a local Attribute Data Type (ADT). TYPE list IS TABLE OF VARCHAR2(3); -- Declare a collection. lv_extension LIST := list('csv','log','bad','dis'); -- Define a default return value. retval NUMBER := 0; -- Declare base target table name. lv_target_table VARCHAR2(30) := 'IMPORT'; lv_foreign_key NUMBER; -- Decalre a cursor to find external tables. CURSOR check_source (cv_table_name VARCHAR2) IS SELECT xt.file_name FROM (SELECT uxt.TABLE_NAME , ixt.column_value AS file_name FROM user_external_tables uxt CROSS JOIN TABLE(list_files(get_directory_path(uxt.default_directory_name))) ixt) xt JOIN user_external_locations xl ON xt.TABLE_NAME = xl.TABLE_NAME AND xt.file_name = xl.location AND xt.TABLE_NAME = UPPER(cv_table_name); -- Declare a cursor to find files and compare for one input file name. CURSOR check_logs (cv_file_name VARCHAR2) IS SELECT list.column_value FROM TABLE(list_files(get_directory_path('UPLOAD_LOGS'))) list JOIN (SELECT cv_file_name AS file_name FROM dual) FILTER ON list.column_value = FILTER.file_name; -- Declare the function as autonomous. PRAGMA AUTONOMOUS_TRANSACTION; BEGIN -- Master loop to check for source and log files. FOR i IN check_source (table_in) LOOP -- Assign next sequence value to local variable. lv_foreign_key := import_master_s.nextval; -- Write the master record and commit it for the autonomous threads. INSERT INTO import_master VALUES (lv_foreign_key,'ITEM_IMPORT_EXT_TABLE'); COMMIT; -- Process all file extensions. FOR j IN 1..lv_extension.COUNT LOOP -- The source data file is confirmed by the CHECK_SOURCE cursor. IF lv_extension(j) = 'csv' THEN -- Load the source data file. -- ---------------------------------------------------------- -- The RETVAL holds success or failure, this approach -- suppresses an error when the file can't be loaded. -- It should only occur when there's no space available -- in the target table. retval := load_clob_from_file(i.file_name ,data_directory_in ,lv_target_table||'_DATA' ,lv_target_table||'_DATA' ,lv_foreign_key); lv_foreign_key := lv_foreign_key + 1; ELSE -- Verify that log file exists before attempting to load it. FOR k IN check_logs (LOWER(table_in)||'.'||lv_extension(j)) LOOP -- Load the log, bad, or dis(card) file. -- ---------------------------------------------------------- -- The RETVAL holds success or failure, as mentioned above. retval := load_clob_from_file(LOWER(table_in)||'.'||lv_extension(j) ,log_directory_in ,lv_target_table||'_'||lv_extension(j) ,lv_target_table||'_'||lv_extension(j) ,lv_foreign_key); END LOOP; END IF; END LOOP; retval := 1; END LOOP; RETURN retval; END; / |
Deleting Files from Virtual Directories
After you’ve read the files through a query and uploaded the source and log files to the database, you need to cleanup the files. This can be done by using another Java library function, provided you granted read, write, and delete privileges to the internal Java permissions file.
The DeleteFile Java library deletes files from the file system. It doesn’t put them in the trash can for final delete, it removes them completely.
Now you can build the Java library that lets you delete a file. A quick caveat, this code includes an AND logical operator that is two ampersands (&&). SQL uses an ampersand (&) for substitution variables. You’ll need to suppress that behavior when you run this code.
You do that by issuing the following command to disable substitution variables in SQL*Plus:
1 | SET DEFINE OFF |
You create the DeleteFile library like this:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 | CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED "DeleteFile" AS // Java import statements import java.io.File; import java.security.AccessControlException; // Class definition. public class DeleteFile { // Define variable(s). private static File file; // Define copyTextFile() method. public static void deleteFile(String fileName) throws AccessControlException { // CREATE files FROM canonical file names. file = NEW File(fileName); // DELETE file(s). IF (file.isFile() && file.delete()) {}}} / |
You need a PL/SQL Wrapper to call the library, and here it is:
1 2 3 4 | CREATE OR REPLACE PROCEDURE delete_file (dfile VARCHAR2) IS LANGUAGE JAVA NAME 'DeleteFile.deleteFile(java.lang.String)'; / |
You can call this separately or embed it inside the UPLOAD_LOGS function, which saves re-writing the logic to find any source or log files.
This has provided you with an external table import framework. You can extend the framework by wrapping the query in an object table function. Such a function would afford you the opportunity to cleanup the source and log files after the query operation.
How to use object types?
A tale of Oracle SQL object types, their constructors, and how you use them. This demonstrates what you can and can’t do and gives brief explanations about why.
The following creates a base SAMPLE_OBJECT
data type and a sample_table
collection of the base SAMPLE_OBJECT
data type.
CREATE OR REPLACE TYPE sample_object IS OBJECT (id NUMBER ,name VARCHAR2(30)); / CREATE OR REPLACE TYPE sample_table IS TABLE OF sample_object; / |
If the base SAMPLE_OBJECT
data type were a Java object, the default constructor of an empty call parameter list would allow you to construct an instance variable. This doesn’t work for an Oracle object type because the default constructor is a formal parameter list of the object attributes in the positional order of their appearance in the declaration statement.
The test case on this concept is:
1 2 3 4 5 6 | DECLARE lv_object_struct SAMPLE_OBJECT := sample_object(); BEGIN NULL; END; / |
Running the program raises the following exception, which points to the object instance constructor from line 2 above:
lv_object_struct SAMPLE_OBJECT := sample_object(); * ERROR at line 2: ORA-06550: line 2, column 37: PLS-00306: wrong number or types of arguments in call to 'SAMPLE_OBJECT' ORA-06550: line 2, column 20: PL/SQL: Item ignored |
Changing the instantiation call to the Oracle design default, two null values let you create
an instance of the SAMPLE_OBJECT
type. The following shows that concept, which works when the base object type allows null values.
1 2 3 4 5 6 | DECLARE lv_object_struct SAMPLE_OBJECT := sample_object(NULL, NULL); BEGIN NULL; END; / |
If you want to have a null parameter constructor for an object type, you must implement a type and type body with an overloaded no argument constructor, like this:
1 2 3 4 5 | CREATE OR REPLACE TYPE sample_object IS OBJECT ( id NUMBER , name VARCHAR2(30) , CONSTRUCTOR FUNCTION sample_object RETURN SELF AS RESULT); / |
1 2 3 4 5 6 7 8 9 | CREATE OR REPLACE TYPE BODY sample_object IS CONSTRUCTOR FUNCTION sample_object RETURN SELF AS RESULT IS sample_obj SAMPLE_OBJECT := sample_object(NULL,NULL); BEGIN SELF := sample_obj; RETURN; END sample_object; END; / |
Unlike Java, the addition of an overloaded constructor doesn’t drop the default constructor. You can also create a single parameter constructor that leverages the sequence like this:
1 2 3 4 5 6 | CREATE OR REPLACE TYPE sample_object IS OBJECT ( id NUMBER , name VARCHAR2(30) , CONSTRUCTOR FUNCTION sample_object RETURN SELF AS RESULT , CONSTRUCTOR FUNCTION sample_object (pv_name VARCHAR2) RETURN SELF AS RESULT); / |
1 2 3 4 5 6 7 8 9 10 11 12 13 14 | CREATE OR REPLACE TYPE BODY sample_object IS CONSTRUCTOR FUNCTION sample_object RETURN SELF AS RESULT IS sample_obj SAMPLE_OBJECT := sample_object(sample_object_id.NEXTVAL,NULL); BEGIN SELF := sample_obj; END sample_object; CONSTRUCTOR FUNCTION sample_object (pv_name VARCHAR2) RETURN SELF AS RESULT IS sample_obj SAMPLE_OBJECT := sample_object(sample_object_id.NEXTVAL,pv_name); BEGIN SELF := sample_obj; RETURN; END sample_object; END; / |
You can test the final object type and body with this anonymous block of code:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | SET SERVEROUTPUT ON SIZE UNLIMITED DECLARE lv_object_struct1 SAMPLE_OBJECT := sample_object(); lv_object_struct2 SAMPLE_OBJECT := sample_object('User Name'); lv_object_struct3 SAMPLE_OBJECT := sample_object(1001,'User Name'); BEGIN dbms_output.put_line('lv_object_struct1.id ['||lv_object_struct1.id||']'); dbms_output.put_line('lv_object_struct1.name ['||lv_object_struct1.name||']'); dbms_output.put_line('lv_object_struct2.id ['||lv_object_struct2.id||']'); dbms_output.put_line('lv_object_struct2.name ['||lv_object_struct2.name||']'); lv_object_struct2.name := 'Changed Name'; dbms_output.put_line('lv_object_struct2.id ['||lv_object_struct2.id||']'); dbms_output.put_line('lv_object_struct2.name ['||lv_object_struct2.name||']'); dbms_output.put_line('lv_object_struct3.id ['||lv_object_struct3.id||']'); dbms_output.put_line('lv_object_struct3.name ['||lv_object_struct3.name||']'); END; / |
It prints to console:
lv_object_struct1.id [1] lv_object_struct1.name [] lv_object_struct2.id [2] lv_object_struct2.name [User Name] lv_object_struct2.id [2] lv_object_struct2.name [Changed Name] lv_object_struct3.id [1001] lv_object_struct3.name [User Name] |
Hope this helps those looking for a quick syntax example and explanation.
Function or Procedure?
Somebody asked for a simple comparison between a PL/SQL pass-by-value function and pass-by-reference procedure, where the procedure uses only an OUT
mode parameter to return the result. This provides examples of both, but please note that a pass-by-value function can be used in SQL or PL/SQL context while a pass-by-reference procedure can only be used in another anonymous of named block PL/SQL program.
The function and procedure let you calculate the value of a number raised to a power of an exponent. The third parameter lets you convert the exponent value to an inverse value, like 2 to 1/2.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 | CREATE OR REPLACE FUNCTION find_root_function ( pv_number BINARY_DOUBLE , pv_power BINARY_DOUBLE , pv_inverse BINARY_INTEGER DEFAULT 0 ) RETURN BINARY_DOUBLE IS -- Declare local variable for return value. lv_result BINARY_DOUBLE; BEGIN -- If the inverse value is anything but zero calculate the inverse of the power. IF pv_inverse = 0 THEN lv_result := POWER(pv_number,pv_power); ELSE lv_result := POWER(pv_number,(1 / pv_power)); END IF; RETURN lv_result; END find_root_function; / |
You can test it with these to queries against the dual
table:
SELECT TO_CHAR(find_root_function(4,3),'99,999.90') FROM dual; SELECT TO_CHAR(find_root_function(125,3,1),'99,999.90') FROM dual; |
The procedure does the same thing as the function. The difference is that the fourth parameter to the procedure returns the value rather than a formal return type like a function.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 | CREATE OR REPLACE PROCEDURE find_root_procedure ( pv_number IN BINARY_DOUBLE , pv_power IN BINARY_DOUBLE , pv_inverse IN BINARY_INTEGER DEFAULT 0 , pv_return OUT BINARY_DOUBLE ) IS BEGIN -- If the inverse value is anything but zero calculate the inverse of the power. IF pv_inverse = 0 THEN pv_return := POWER(pv_number,pv_power); ELSE dbms_output.put_line('here'); pv_return := POWER(pv_number,(1 / pv_power)); END IF; END find_root_procedure; / |
You can test it inside an anonymous block PL/SQL program, like this:
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 | DECLARE -- Declare input variables. lv_input BINARY_DOUBLE; lv_power BINARY_DOUBLE; lv_inverse BINARY_INTEGER; lv_output BINARY_DOUBLE; BEGIN -- Assign input values to variables. lv_input := '&1'; lv_power := '&2'; lv_inverse := '&3'; -- Test raising to a power. find_root_procedure(lv_input, lv_power, lv_inverse, lv_output); dbms_output.put_line(TO_CHAR(lv_output,'99,999.90')); -- Test raising to an inverse power. find_root_procedure(lv_input, lv_power, lv_inverse, lv_output); dbms_output.put_line(TO_CHAR(lv_output,'99,999.90')); END; / |
You can test it inside an anonymous block PL/SQL program, like the following example. For reference, the difference between PL/SQL and the SQL*Plus environment is large. The EXECUTE
call is correct in SQL*Plus but would be incorrect inside a PL/SQL block for a Native Dynamic SQL (NDS) call. Inside a PL/SQL block you would use EXECUTE IMMEDIATE
because it dispatches a call from the current running scope to a nested scope operation (see comment 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 | -- SQL*Plus Test. VARIABLE sv_input BINARY_DOUBLE VARIABLE sv_power BINARY_DOUBLE VARIABLE sv_inverse BINARY_DOUBLE VARIABLE sv_output BINARY_DOUBLE -- Verify the null value of the session variable. SELECT :sv_output AS ":sv_output" FROM dual; BEGIN -- Prompt for local assignments and initialize output variable. :sv_input := '&1'; :sv_power := '&2'; :sv_inverse := '&3'; :sv_output := 0; END; / -- Run the procedure in the SQL*Plus scope. EXECUTE find_root_procedure(:sv_input, :sv_power, :sv_inverse, :sv_output); -- Query the new value of the session variable. SELECT TO_CHAR(:sv_output,'99,999.90') AS ":output" FROM dual; |
As usual, I hope this helps folks beyond the one who asked. Comments are always welcome.
Java Generics in Oracle
Somebody posed the question about using a Comparator in the sorting examples provided in this earlier post on Updating Table View Columns (columns using a Varray or Nested Table of a single scalar data type). It seems the individual thought that you can’t use Java Generics inside an Oracle Database 11g’s Java libraries. It’s seems odd since they’ve been around since Java 5.
You can use Generics like those shown in the following example. It builds on explanation from the prior post. If you want to get the whole set of facts click the link above but you should have all the code you need in this post.
An example like this requires you first define a collection of strings in the database. This one uses the following definition:
1 2 | CREATE OR REPLACE TYPE stringlist IS TABLE OF VARCHAR2(4000); / |
This creates the Java library source, and line 21 shows the use of Generics in the instantiation of a anonymous Comparator class:
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 | CREATE OR REPLACE AND COMPILE JAVA SOURCE NAMED "SortList" AS // Import required classes. import java.io.*; import java.security.AccessControlException; import java.sql.*; import java.util.Arrays; import java.util.Comparator; import oracle.sql.driver.*; import oracle.sql.ArrayDescriptor; import oracle.sql.ARRAY; // Define class. public class Sorting { public static ARRAY sortTitleCaseList(oracle.sql.ARRAY list) throws SQLException, AccessControlException { // Convert Oracle data type to Java data type. String[] unsorted = (String[])list.getArray(); // Sort elements. Arrays.sort(unsorted, new Comparator<String>() { public int compare(String s1, String s2) { // Declare a sorting key integer for the return value. int sortKey; // Check if lowercase words match and sort on first letter only. if (s1.toLowerCase().compareTo(s2.toLowerCase()) == 0) sortKey = s1.substring(0,1).compareTo(s2.substring(0,1)); else sortKey = s1.toLowerCase().compareTo(s2.toLowerCase()); // Return the sorting index. return sortKey; }}); // Define a connection (this is for Oracle 11g). Connection conn = DriverManager.getConnection("jdbc:default:connection:"); // Declare a mapping to the schema-level SQL collection type. ArrayDescriptor arrayDescriptor = new ArrayDescriptor("STRINGLIST",conn); // Translate the Java String{} to the Oracle SQL collection type. ARRAY sorted = new ARRAY(arrayDescriptor,conn,((Object[])unsorted)); // Return the sorted list. return sorted; } } / |
The PL/SQL wrapper for this class would be:
1 2 3 4 | CREATE OR REPLACE FUNCTION sortTitleCaseList(list STRINGLIST) RETURN STRINGLIST IS LANGUAGE JAVA NAME 'Sorting.sortNaturalCaseList(oracle.sql.ARRAY) return oracle.sql.ARRAY'; / |
You can test the code with the following query:
1 2 | SELECT column_value FROM TABLE(sortTitleCaseList(stringlist('Oranges','apples','Apples','Bananas','Apricots','apricots'))); |
It sorts the strings based on a title case sort, like:
COLUMN_VALUE ------------------------ Apples apples Apricots apricots Bananas Oranges 6 rows selected. |
If you want a quick example of a Generic Collection sort operation outside of the database, here a sample file.
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 | // Import required classes. import java.util.Arrays; import java.util.Comparator; /** * An example of using a Comparator sort. */ public class SortStaticString { /* * Sort the instance array. */ public static String[] sortTitleCaseList(String[] list) { // Sort elements by title case. Arrays.sort(list, new Comparator<String>() { public int compare(String s1, String s2) { // Declare a sorting key integer for the return value. int sortKey; // Check if lowercase words match and sort on first letter only. if (s1.toLowerCase().compareTo(s2.toLowerCase()) == 0) sortKey = s1.substring(0,1).compareTo(s2.substring(0,1)); else sortKey = s1.toLowerCase().compareTo(s2.toLowerCase()); // Return the sorting index. return sortKey; }}); // Return the sorted Index. return list; } /* * Test case. */ public static void main(String[] args) { // Construct and instance and apply sort method. args = SortStaticString.sortTitleCaseList(args); // Print the title case sorted list. for (int i = 0; i < args.length; i++) { System.out.println(args[i]); } } } |
You would call the SortStaticString class as follows:
java SortStaticString apples Oranges Pears Apples orange Grapefruit |
I hope this helps the interested party and any others looking for a sample file. 😉
Oracle 11gR2 on Windows 7
Here are step-by-step instructions for installing Oracle Database 11g Release 2 on Windows 7 (Oracle 12c is here). It’s provided in response to questions posted on my step-by-step instructions for installing Oracle 11gR1 on Windows 7. For reference, I posted the former because it didn’t work without intervention. I hadn’t updated step-by-step instructions because Oracle Database 11g Release 2 has always worked for me when installing on Windows 7.
A number of students and blog readers have mentioned that it didn’t work for them. My guess is that they had configuration issues within the Windows 7 environment. There are some Windows 7 configuration caveats before you perform this installation, and they are:
Windows 7 Configuration Steps
- Make sure you have at least 3 GB of memory on your Windows PC, or that you can allocate 4 GB of memory to your virtual machine (the latter typically requires 8 GB of real memory to avoid extensive disk caching of memory).
- Install Oracle’s SJDK and run time for Java 6 or 7 on Windows 7 (I installed Java 7). Although either work with the database, you need the Java 6 SDK 32-bit version (at least SJDK 1.6.0_4) for Oracle SQL Developer. This means you need to download the 32-bit version even when you’re installing the 64-bit Oracle Database 11g version. The SQL Developer fix is found in this blog post.
- Disable Microsoft’s User Access Controls (UAC). I blogged about a set of Windows 7 gripes, and the second point shows you the screen shots that let you disable UAC on Windows 7.
- Configure your
C:\Windows\System32\drivers\etc\hosts
file. Use lines 1 through 3 when you’re using a DHCP IP address, and lines 1 through 4 when you’re using a static IP address. If you want to set a static IP address, check this old post on how to set a static IP address. Please note that thehostname
needs to be lowercase.
1 2 3 4 | 127.0.0.1 localhost
::1 localhost
127.0.0.1 mclaughlinmysql mclaughlinmysql.techtinker.com
172.26.126.131 mclaughlinmysql mclaughlinmysql.techtinker.com |
- Create a user account name that doesn’t have a white space, like
McLaughlinM
in the screen shots, and assign it Administrator privileges. - The Oracle Enterprise Manager (OEM) uses port ranges above 5,000, which according to Microsoft requires that you set
MaxUserPort
key in the Windows Registry. You can find more details at this Microsoft Support page. Personally, I haven’t found this necessary and after adding it to please somebody without setting it everything ran fine in Windows 7.
Registry key: HKEY_LOCAL_MACHINE\SYSTEM\CurrentControlSet\Services\Tcpip\Parameters
Value Name | MaxUserPort |
Value Type | DWORD |
Value Data | 65534 |
Value Range | 5000-65534 (decimal) |
Value Default | 0x1388 (5000 decimal) |
Description | This parameter controls the maximum port number that is used when a program requests any available user port from the system. Typically, ephemeral (short-lived) ports are allocated between the values of 1024 and 5000 inclusive. After the release of security bulletin MS08-037, the behavior of Windows Server 2003 was changed to more closely match that of Windows Server 2008 and Windows Vista. For more information about Microsoft security bulletin MS08-037 |
Oracle 11g Release 2 Installation Steps
- The Oracle Database 11g Release 2 files are broken down into two zip files on the Oracle site. That means you need to download both files, and then expand them into an installation directory. I called my installation directory
C:\OracleInstall
, but you can call it whatever works for you. Here’s a screen shot of the directory after expanding both compressed files (done with WinZip 15).
database
directory (or folder). Within the installation folder (C:\OracleInstall\database
), you double click on the oui
icon to launch (start) the Oracle Universal Installer. It’ll open a command prompt that may dwell on the screen for a few seconds up to maybe fifteen seconds.
- It’s a good idea to provide an email address for security updates no matter what. You can uncheck the box if you don’t want updates via Oracle Support Services. Click the Next button to continue.
- Most developers want to Create and configure a database. If that’s your desire, leave the default radio button checked. Click the Next button to continue.
- Most developers install their test instance on a desktop or laptop. If that’s your desire, leave the default Desktop Class radio button checked. Click the Next button to continue.
- These are default settings and generally the easiest to use. I’d suggest you change the Character Set drop down to Unicode. Then, enter a password twice. Oracle requires that you use at least one capital letter and one number in a 6 character or more long password. Click the Next button to continue.
- The next screen is a progress bar that checks for prerequisites. You shouldn’t have to do anything here because it automatically advances you to the next dialog screen. This generally takes less than a minute to run but can take two or so. If you’re much beyond 3 minutes there may be a resource problem with your Windows PC or virtual machine.
- This shows you all the selected values for the installation. Unless you want to abort the installation, click the Finish button to proceed.
- This screen is the main progress bar, and you’ll be here somewhere between 5 and 10 minutes. The downside is that there are some dialogs that will popup during this phase and you need to authorize them, so it’s a bad time to take a break.
- The first popup screen requires you to authorize the Java runtime to call home. You should click the Allow Access button to proceed.
- When the progress bar starts configuring the instance, failures can occur. The first may occur during the network configuration, which typically happens if you didn’t preconfigure the
hosts
file. You don’t need to do anything but watch here unless the installer triggers an error.
- The following progress bar is launched by the Oracle Database Configuration Assistant. It typically runs without a problem. You don’t need to do anything but watch here unless the installer triggers an error. This takes a few minutes, and unfortunately requires you to stick aroung to again authorize Java.
- The second popup screen requires you to authorize the Java runtime to call home. You should click the Allow Access button to proceed.
- The third and last popup screen asks you to whether you want to open other scheme. Generally, you should click the OK button to proceed.
- The next dialog shows you that the network and database instances are configured. It’s also running the OEM (Oracle Enterprise Manager) installation. You can wait here but it won’t be a long wait.
- This is the last dialog and says you’ve installed Oracle Database 11g Release 2 successfully. You can the Close button to complete the installation.
The next step is probably running Oracle Enterprise Manager (OEM). I’ve recently added this post, which arose from a question. It shows you how to run the DB Console.
Also, it’s possible that you could have a problem launching SQL Developer. If so, check how to set the proper JVM for SQL Developer post.
As always, I hope this helps folks.