Archive for the ‘pl/sql’ Category
Oracle Legacy Workaround
We had a discussion today about how you can manage legacy code that you can’t change. For example, how do you access a PL/SQL function in PHP that returns a PL/SQL table of record structures? PL/SQL tables, index-by tables, or associate arrays are one in the same dependent on the release documentation. They’ve been available since Oracle 7.3 (roughly 15+ years).
You’ve a handful of solutions but I think the best is to wrap it in a Pipelined Table function (more on that in this older post). Here’s an example of such a package, wrapper function, and PHP program calling the wrapper function (command-line only PHP sample code).
Let’s say you have the following type of legacy package specification 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 45 46 47 48 49 50 51 52 53 54 55 56 57 58 | -- Create the package specification. CREATE OR REPLACE PACKAGE lib IS /* Define a record structure. */ TYPE movie_title_record IS RECORD ( title VARCHAR2(60) , subtitle VARCHAR2(60)); /* Define an associative array of a package record structure. */ TYPE movie_title_table IS TABLE OF movie_title_record INDEX BY BINARY_INTEGER; /* Define a prototype of a package function. */ FUNCTION get_movie ( pv_title VARCHAR2 ) RETURN lib.movie_title_table; END lib; / -- Create the package body. CREATE OR REPLACE PACKAGE BODY lib IS /* Implement the package function. */ FUNCTION get_movie ( pv_title VARCHAR2 ) RETURN lib.movie_title_table IS /* Declare a counter variable. */ lv_counter INTEGER := 1; /* Declare an instance of the package nested table and initialize it. */ lv_table LIB.MOVIE_TITLE_TABLE := lib.movie_title_table(); /* Define a parameterized cursor to read values from the ITEM table. */ CURSOR c ( cv_partial_title VARCHAR2 ) IS SELECT i.item_title , i.item_subtitle FROM item i WHERE i.item_title LIKE '%'||cv_partial_title||'%'; BEGIN /* Read the contents of the parameterized cursor. */ FOR i IN c (pv_title) LOOP /* Extend space, assign values from the cursor to the record structure of the nested table, and increment counter. */ lv_table.EXTEND; lv_table(lv_counter) := i; lv_counter := lv_counter + 1; END LOOP; /* Return PL/SQL-scope nested table. */ RETURN lv_table; END get_movie; END lib; / |
You can wrap the lib
package’s get_movie
function with a schema-level function provided you convert the older associative array to a PL/SQL-scope nested table. You can do that in two steps. The first requires that you create a wrapper package specification, like the following example. The second step requires you to write a conversion wrapper function, shown later.
The table is dependent on the named record structure from the lib
, and as such the packages are now tightly coupled. This is not uncommon when you can’t fix a vendors legacy code set.
1 2 3 4 5 6 7 | CREATE OR REPLACE PACKAGE wlib IS /* Define a nested table of a package record structure. */ TYPE movie_title_table IS TABLE OF lib.movie_title_record; END wlib; / |
The wrapper function also converts the Oracle Database 7.3 forward data type to an Oracle Database 8.0.3 data type, and then pipes it into a SQL aggregate table. SQL aggregate tables are valid call parameters in the SQL-context. The TABLE
function converts the collection of record structures into an inline view or derived table, as you’ll see a little farther along.
You should note that the return type of this function differs from the original package-level get_movie
function. The former uses an associative array defined in the lib
, while the latter uses a nested table defined in the wlib
package.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 | CREATE OR REPLACE FUNCTION get_movie ( pv_title VARCHAR2 ) RETURN wlib.movie_title_table PIPELINED IS /* Define a PL/SQL-scope associative array (Available Oracle 7.3). */ lv_table_source LIB.MOVIE_TITLE_TABLE; /* Define a PL/SQL-scope nested table (Available Oracle 8.0.3). */ lv_table_target WLIB.MOVIE_TITLE_TABLE := wlib.movie_title_table(); BEGIN /* Assign the results of a PL/SQL-scope call to the package function. */ lv_table_source := lib.get_movie(dbms_assert.simple_sql_name(pv_title)); /* Read the contents of the PL/SQL-scope nested table into a PIPE ROW. */ FOR i IN 1..lv_table_source.COUNT LOOP lv_table_target.EXTEND; lv_table_target(i) := lv_table_source(i); PIPE ROW(lv_table_target(i)); END LOOP; END; / |
You can test this exclusively in SQL*Plus with the following formatting and query. The TABLE
function translates the returned array into an inline view or derived table for processing.
-- Format columns for display with SQL*Plus. COLUMN title FORMAT A20 HEADING "Movie Title" COLUMN subtitle FORMAT A20 HEADING "Movie Subtilte" -- Select the contents of the schema-level function in a SQL-context. SELECT * FROM TABLE(get_movie('Star')); |
If you’re using my sample code from the Oracle Database 11g PL/SQL Programming book, you should see:
Movie Title Movie Subtilte -------------------- -------------------- Star Wars I Phantom Menace Star Wars II Attack of the Clones Star Wars II Attack of the Clones Star Wars III Revenge of the Sith |
The following is a simple command-line PHP program that calls the wrapper function. It calls the wrapper function, which calls the lib.get_movie()
function, and it converts the PL/SQL data type from an associative array (Oracle 7.3+ data type) to a nested table (Oracle 8.0.3+ data type). The nested table is defined in the wlib
library, which supplements rather than replaces the original lib
library.
The last thing that the wrapper function does is transform the associative array result into a nested table before placing it in the pipe (this process is known as a Pipelined Table function). Only nested table and varray data types may be piped into a SQL aggregate table. Then, the external programming language can manage the output as if it were a query.
Here’s the PHP program:
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 | <?php // Connect to the database. if ($c = oci_connect("student","student","localhost/orcl")) { // Parsing a statement into a digestable SQL statement. $s = oci_parse($c,"SELECT * FROM TABLE(get_movie('Star'))"); // Execute the parsed statement. oci_execute($s,OCI_DEFAULT); // Store control variable for the number of columns returned by the statement. $columns = oci_num_fields($s); // Find the number of columns, loop through them, and write their column name metadata. for ($i = 1; $i <= $columns; $i++) { // Print the column names, also known as field names. print oci_field_name($s,$i); // Define a variable. $line; /* Check whether a variable is declared and pad it. * The numeric literal is for my convenience because the maximum size * of possible returns is known. In a real situation, you'd use the * following str_pad() call: * * str_pad($temp,oci_field_size($s,$i),"-") */ if (!isset($line)) $line .= str_pad($temp,15,"-"); else $line .= " ".str_pad($temp,20,"-"); /* One of the values requires a double tab to line up, otherwise this practice is unwise. */ if ($i < $columns) print "\t\t"; } // Print line return for the header and a line to mimic Oracle SQL*Plus output. print "\n"; print $line .= "\n"; // Process row-by-row data returned when data is returned. while (oci_fetch($s)) { // Process column-by-column data returned for each row. for ($i = 1; $i <= $columns; $i++) { print oci_result($s,$i); if ($i < $columns) print "\t"; } // Print line return for the row of data returned. print "\n"; } // Release resources. oci_close($c); // Explicitly free any resources. oci_free_statement($s); oci_free_cursor($c); } ?> |
Assuming you call this callOracle.php
, you can call it from the command-line with this syntax:
php callOracle.php |
It prints, like it would in SQL*Plus:
TITLE SUBTITLE --------------- -------------------- Star Wars I Phantom Menace Star Wars II Attack of the Clones Star Wars II Attack of the Clones Star Wars III Revenge of the Sith |
Hope that helps those working with legacy Oracle code.
Two-stepping Sequences
Sometimes I’m amazed at things that come up. A student wondered why the sequences were incrementing by two when they’re defined to increment by one. It turns out that they were using Oracle APEX to create SQL statements to build a table, constraints, and a auto-numbering sequence trigger. Before executing the code, they’d copy it into their re-runnable script that created their schema.
Here’s an example of code that was generated by APEX for a table:
-- Create the table. CREATE TABLE onesy ( onesy_id NUMBER , onesy_text VARCHAR2(20)); -- Add the primary key constraint. ALTER TABLE onesy ADD CONSTRAINT onesy_seq PRIMARY KEY (onesy_id); -- Add a database trigger. CREATE OR REPLACE TRIGGER onesy_trg BEFORE INSERT ON onesy FOR EACH ROW BEGIN :NEW.onesy_id := onesy_s1.NEXTVAL; END; / |
This works in APEX because it doesn’t create forms that call onesy_seq.NEXTVAL
but they did create that logic in their forms. The INSERT
statement would look like:
INSERT INTO onesy VALUES (onesy_seq.NEXTVAL, 'One'); |
Therefore, the INSERT
statement incremented the trigger by one and the database trigger incremented it by one. The result is that sequences two-step, which isn’t effective or the desired behavior.
After I explained the two-step problem, they asked if they could only call the trigger when the primary key value was null. While they could do that like this:
1 2 3 4 5 6 7 8 9 | -- Add a database trigger. CREATE OR REPLACE TRIGGER onesy_trg BEFORE INSERT ON onesy FOR EACH ROW WHEN (NEW.one_id IS NULL) BEGIN :NEW.onesy_id := onesy_s1.NEXTVAL; END; / |
The problem is that this type of trigger doesn’t stop other possible problems. While it prevents two-stepping the sequence, it doesn’t prevent two other errors.
One possible error that isn’t managed in this scenario is the use of numeric literals beyond the next value of the sequence. It writes the row but eventually the sequence catches up to the higher value and a production insert would fail. It would raise the following exception.
INSERT INTO onesy (onesy_text) VALUES ('Eight') * ERROR at line 1: ORA-00001: UNIQUE CONSTRAINT (STUDENT.PK_ONE) violated |
Another possible error can occur when you use a bulk insert operation. Assuming you’re inserting 500 rows at a go, you query the maximum value of the onesy_id
column and then create an array of 500 numbers. Then, you perform the bulk INSERT
statement. The next call to the trigger would raise another ORA-00001
unique constraint error.
Yes, you could lock the table before you perform the bulk operation. After the bulk operation you would drop and recreate the sequence with a new value equal to the maximum value in the column, and unlock the table. This limits concurrency of operation. You could treat these bulk operations as off-line transactions (batch processing) and it would work nicely.
You could also implement a policy that no bulk operations provide generated column values that link to a sequence. Beyond it’s impracticality to manage, that type of restriction does limit the benefit of bulk operations.
The students wanted a solution. So, here’s my take on a trigger that prevents collision with values above the next sequence value. It assumes that bulk operations will be performed as batch processing where you can disable this trigger.
This trigger disallows numeric literals, logs any attempts to use them, and stops processing when an INSERT
statement tries to use anything other than the .NEXTVAL
of the sequence. It will only work in an Oracle Database 11g database because the context of using a sequence_name.CURRVAL
in a comparison isn’t supported in prior releases. The onesy
table is renamed the one
table in the example.
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 | -- Create a sequence for table ONE that starts with 1 and increments by 1. CREATE SEQUENCE msg_s1; CREATE OR REPLACE TRIGGER one_t1 BEFORE INSERT ON one FOR EACH ROW DECLARE /* Define an autonomous transaction scope to the trigger. */ PRAGMA AUTONOMOUS_TRANSACTION; /* Declare a local exception raised when a .CURRVAL pseudo column for a sequence is called before a .NEXTVAL for the same sequence in the same session. */ no_sequence_in_scope EXCEPTION; PRAGMA EXCEPTION_INIT(no_sequence_in_scope,-08002); BEGIN /* Check if surrogate key is provided and the sequence not out of transaction scope. */ IF :NEW.one_id IS NOT NULL AND NOT :NEW.one_id = one_s1.CURRVAL THEN /* Write message when sequence value is a numeric literal not a sequence generated value but a one_s1.NEXTVAL was previously called in the session. Commit after write or information is lost because it throws an user-defined exception. */ INSERT INTO msg VALUES (msg_s1.NEXTVAL,'ID value less or greater than .NEXTVAL ['||:NEW.one_id||']['||:NEW.one_text||'].'); COMMIT; /* Stop processing by throwing exception. */ RAISE_APPLICATION_ERROR(-20002,'ID provided by calling scope is not next sequence value ['||:NEW.one_id||']['||:NEW.one_text||'].'); ELSIF :NEW.one_id = one_s1.CURRVAL THEN /* Do nothing, calling scope is correct with a one_s1.NEXTVAL sequence call. */ NULL; ELSE /* Increment sequence and assign a value when one isn't provided, like a NULL value. */ :NEW.one_id := one_s1.NEXTVAL; END IF; EXCEPTION /* Handle a no sequence in scope error. */ WHEN no_sequence_in_scope THEN /* Write and commit log message for error. */ INSERT INTO msg VALUES (msg_s1.NEXTVAL,'ID provided by calling scope is invalid ['||:NEW.one_id||']['||:NEW.one_text||'].'); COMMIT; /* Stop processing by throwing an exception. */ RAISE_APPLICATION_ERROR(-20001,'Not a sequence generated value ['||:NEW.one_id||'].'); END; / |
Since anonymous transaction triggers are tricky, it’s important to note that the message writing requires two commits. One before raising the exception when the .CURRVAL
is in session scope and another in the exception handler before raising the error. If you forget those COMMIT
statements, this is a sample of the error stack:
INSERT INTO one VALUES (one_s1.nextval,'Six') * ERROR at line 1: ORA-06519: active autonomous TRANSACTION detected AND rolled back ORA-06512: at "STUDENT.ONE_T1", line 31 ORA-04088: error during execution OF TRIGGER 'STUDENT.ONE_T1' |
The trigger raises the following type of exceptions for an offending INSERT
statement. The first occurs when the sequence is valid in the session scope, like:
DECLARE * ERROR at line 1: ORA-20001: NOT a SEQUENCE generated VALUE [1]. ORA-06512: at "STUDENT.ONE_T1", line 48 ORA-04088: error during execution OF TRIGGER 'STUDENT.ONE_T1' ORA-06512: at line 15 |
The second occurs when the sequence isn’t valid in the session scope.
INSERT INTO one VALUES (401,'Nine') * ERROR at line 1: ORA-20002: ID provided BY calling scope IS NOT NEXT SEQUENCE VALUE [401][Nine]. ORA-06512: at "STUDENT.ONE_T1", line 24 ORA-04088: error during execution OF TRIGGER 'STUDENT.ONE_T1' |
A value that’s below the current high-watermark of the sequence raises a unique constraint, like this:
INSERT INTO one VALUES (1,'Eight') * ERROR at line 1: ORA-00001: UNIQUE CONSTRAINT (STUDENT.PK_ONE) violated |
The following is a script with all the necessary code components to test the example.
Oracle Script ↓
Unfold this if you’d like to see the complete test case.
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 128 129 130 131 132 133 134 135 136 137 138 139 140 | -- Conditionally drop tables and sequences. BEGIN FOR i IN (SELECT object_name, object_type FROM user_objects WHERE object_name IN ('ONE','ONE_S1','MSG','MSG_S1')) LOOP IF i.object_name = 'TABLE' THEN EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name||' CASCADE CONSTRAINTS'; ELSE EXECUTE IMMEDIATE 'DROP '||i.object_type||' '||i.object_name; END IF; END LOOP; END; / -- Create a table ONE. CREATE TABLE one (one_id NUMBER CONSTRAINT pk_one PRIMARY KEY, one_text VARCHAR2(20)); -- Create a sequence for table ONE that starts with 1 and increments by 1. CREATE SEQUENCE one_s1; -- Create a table MSG. CREATE TABLE msg (msg_id NUMBER, msg_text VARCHAR2(80)); -- Create a sequence for table ONE that starts with 1 and increments by 1. CREATE SEQUENCE msg_s1; -- Create or replace trigger. CREATE OR REPLACE TRIGGER one_t1 BEFORE INSERT ON one FOR EACH ROW DECLARE /* Define an autonomous transaction scope to the trigger. */ PRAGMA AUTONOMOUS_TRANSACTION; /* Declare a local exception raised when a .CURRVAL pseudo column for a sequence is called before a .NEXTVAL for the same sequence in the same session. */ no_sequence_in_scope EXCEPTION; PRAGMA EXCEPTION_INIT(no_sequence_in_scope,-08002); BEGIN /* Check if surrogate key is provided and the sequence not out of transaction scope. */ IF :NEW.one_id IS NOT NULL AND NOT :NEW.one_id = one_s1.CURRVAL THEN /* Write message when sequence value is a numeric literal not a sequence generated value but a one_s1.NEXTVAL was previously called in the session. Commit after write or information is lost because it throws an user-defined exception. */ INSERT INTO msg VALUES (msg_s1.NEXTVAL,'ID value less or greater than .NEXTVAL ['||:NEW.one_id||']['||:NEW.one_text||'].'); COMMIT; /* Stop processing by throwing exception. */ RAISE_APPLICATION_ERROR(-20002,'ID provided by calling scope is not next sequence value ['||:NEW.one_id||']['||:NEW.one_text||'].'); ELSIF :NEW.one_id = one_s1.CURRVAL THEN /* Do nothing, calling scope is correct with a one_s1.NEXTVAL sequence call. */ NULL; ELSE /* Increment sequence and assign a value when one isn't provided, like a NULL value. */ :NEW.one_id := one_s1.NEXTVAL; END IF; EXCEPTION /* Handle a no sequence in scope error. */ WHEN no_sequence_in_scope THEN /* Write and commit log message for error. */ INSERT INTO msg VALUES (msg_s1.NEXTVAL,'ID provided by calling scope is invalid ['||:NEW.one_id||']['||:NEW.one_text||'].'); COMMIT; /* Stop processing by throwing an exception. */ RAISE_APPLICATION_ERROR(-20001,'Not a sequence generated value ['||:NEW.one_id||'].'); END; / -- Define a schema collection of strings. CREATE OR REPLACE TYPE one_index AS TABLE OF VARCHAR2(20); / -- Define a schema collection of strings. CREATE OR REPLACE TYPE one_list AS TABLE OF VARCHAR2(20); / -- Anonymous block bulk testing program. DECLARE -- Declare two scalar collection variables. lv_index ONE_INDEX := one_index(); lv_list ONE_LIST := one_list('One','Two','Three','Four','Five'); BEGIN -- Initialize the collection of the ONE_INDEX collection. lv_index.EXTEND(lv_list.COUNT); FOR i IN lv_list.FIRST..lv_list.LAST LOOP dbms_output.put_line('['||i||']['||lv_list(i)||']'); lv_index(i) := i; END LOOP; -- Perform a trivial example of a bulk insert. FORALL i IN lv_list.FIRST..lv_list.LAST INSERT INTO one VALUES (lv_index(i),lv_list(i)); END; / -- Testing INSERT statements until sequence value increments beyond bulk insert values. INSERT INTO one VALUES (6,'Six'); INSERT INTO one VALUES (one_s1.nextval,'Seven'); INSERT INTO one VALUES (1,'Eight'); INSERT INTO one VALUES (401,'Nine'); INSERT INTO one VALUES (NULL,'Ten'); COLUMN msg_id FORMAT 999 HEADING "Msg|ID" COLUMN msg_text FORMAT A72 HEADING "Msg Text" -- SELECT * FROM one; SELECT * FROM msg; -- Anonymous block bulk testing program. DECLARE -- Declare two scalar collection variables. lv_list ONE_LIST := one_list('Twenty-one','Twenty-two','Twenty-three','Twenty-four','Twenty-five'); BEGIN -- Perform a trivial example of a bulk insert. FORALL i IN lv_list.FIRST..lv_list.LAST INSERT INTO one VALUES (NULL,lv_list(i)); END; / -- Query tables. SELECT * FROM one; SELECT * FROM msg; |
If I’ve fat fingered any typing or made logical errors, please let me know.
Correlated Update Statement
My students wanted some additional examples on correlated update statements. I’ve been struggling with what the right way may be to illustrate them.
Correlated subqueries are a hard concept to explain to those new to SQL. While correlated update statements seem impossibly obscure to many or inordinately complex. New SQL developers often flee to the comfort of procedural programs when it comes to update statements.
This uses my video store data model. It’s a correlated update statement to clean up potential corrupt data. More or less something a DBA might run to ensure a business rule hasn’t been violated over time. It checks for the correct foreign key value in a table when a dependent table contains one or more than one row of data.
The aqua-green box highlights a subquery that aggregates foreign key columns and groups the result with the foreign key value. The results from this subquery become a run-time view or derived table. The result set is a foreign key value and a substitute string literal value for each row in the contact table. These results correlate to the update statement’s rows based on the input parameter. The input parameter is a column from each updated row.
A unique key (or check constraint) exists on the combination of the common_lookup_table, common_lookup_column, and common_lookup_type columns. This ensures that only one row is returned and assigned to the member_type column in the member table. The update statement naturally works in either Oracle or MySQL without any porting changes.
Correlated Update Statement ↓
Expand this section to see the clear text for the foregoing image.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 | UPDATE member m SET member_type = (SELECT common_lookup_id FROM common_lookup WHERE common_lookup_table = 'MEMBER' AND common_lookup_column = 'MEMBER_TYPE' AND common_lookup_type = (SELECT dt.member_type FROM (SELECT c.member_id , CASE WHEN COUNT(c.member_id) > 1 THEN 'GROUP' ELSE 'INDIVIDUAL' END AS member_type FROM contact c GROUP BY c.member_id) dt WHERE dt.member_id = m.member_id)); |
While this type of solution is powerful in its own right, I thought it might be interesting to see their procedural equivalents. These correlated subqueries run for each row returned by the master query (or outermost statement). Therefore, they act like functions.
Procedural equivalents (or user-defined functions) simplify the update statement like so:
UPDATE member m SET member_type = get_member_type(m.member_id); |
If you’re interested in seeing how you would implement this solution in a user-defined function, just expand the dropdown that interest you.
Oracle User-Defined Function (UDF) ↓
Expand this section to see how to map this logic to a 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 | CREATE OR REPLACE FUNCTION get_member_type (pv_member_id NUMBER) RETURN NUMBER IS -- Define a collection of strings. TYPE type_options IS TABLE OF VARCHAR2(10); -- Declare local variables. lv_dependent NUMBER := 1; lv_return_id NUMBER; -- Declare a local variable of the collection. lv_member_type TYPE_OPTIONS := type_options('INDIVIDUAL','GROUP'); -- Define a dynamic cursor to count the number of foreign key values. CURSOR count_contact (cv_member_id NUMBER) IS SELECT COUNT(c.member_id) FROM contact c WHERE c.member_id = cv_member_id; -- Define a dynamic cursor to find a key for an individual or group member type. CURSOR get_lookup_id (cv_type VARCHAR2) IS SELECT common_lookup_id FROM common_lookup WHERE common_lookup_context = 'MEMBER' AND common_lookup_type = cv_type; BEGIN -- Get the number of foreign key values for a contact. OPEN count_contact(pv_member_id); FETCH count_contact INTO lv_dependent; CLOSE count_contact; -- Open the dynamic cursor with the required value. IF lv_dependent = 1 THEN OPEN get_lookup_id(lv_member_type(1)); ELSE OPEN get_lookup_id(lv_member_type(2)); END IF; -- Get the correct surrogate primary key value. FETCH get_lookup_id INTO lv_return_id; CLOSE get_lookup_id; -- Return the correct primary key for use as a foreign key. RETURN lv_return_id; END; / |
MySQL User-Defined Function (UDF) ↓
Expand this section to see how to map this logic to a Persistent Stored Module (PSM) 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 | SELECT 'DROP FUNCTION IF EXISTS get_member_type' AS "Statement"; DROP FUNCTION IF EXISTS get_member_type; SELECT 'DELIMITER $$' AS "Statement"; DELIMITER $$ SELECT 'CREATE FUNCTION get_member_type' AS "Statement"$$ CREATE FUNCTION get_member_type(pv_member_id INT) RETURNS INT BEGIN /* Define three local variables. */ DECLARE lv_contact_number INT; DECLARE lv_member_type CHAR(30); DECLARE lv_return_value INT; /* Define a dynamic cursor to count the number of foreign key values. */ DECLARE contact_cursor CURSOR FOR SELECT COUNT(c.member_id) FROM contact c WHERE c.member_id = pv_member_id; /* Define a dynamic cursor to find a key for an individual or group member type. */ DECLARE common_lookup_cursor CURSOR FOR SELECT common_lookup_id FROM common_lookup WHERE common_lookup_table = 'MEMBER' AND common_lookup_column = 'MEMBER_TYPE' AND common_lookup_type = lv_member_type; /* Get the number of foreign key values for a contact. */ OPEN contact_cursor; FETCH contact_cursor INTO lv_contact_number; CLOSE contact_cursor; /* Assign group membership when more than one foreign key value is found; and assign individual membership when only one foreign key value is found. */ IF lv_contact_number > 1 THEN SET lv_member_type = 'GROUP'; ELSE SET lv_member_type = 'INDIVIDUAL'; END IF; /* Get the correct surrogate primary key value. */ OPEN common_lookup_cursor; FETCH common_lookup_cursor INTO lv_return_value; CLOSE common_lookup_cursor; /* Return the correct primary key for use as a foreign key. */ RETURN lv_return_value; END; $$ SELECT 'DELIMITER $$' AS "Statement"$$ DELIMITER ; |
You can query the results of the update statement with the following.
Change Confirmation Query ↓
Expand this section to see the query that lets you examine the changes. It runs in either Oracle or MySQL without any changes.
1 2 3 4 5 6 7 8 9 10 11 | SELECT m.member_id , dt.quantity , m.member_type , cl.common_lookup_type FROM member m JOIN (SELECT member_id , COUNT(c.member_id) AS quantity FROM contact c GROUP BY c.member_id) dt ON m.member_id = dt.member_id JOIN common_lookup cl ON m.member_type = cl.common_lookup_id ORDER BY m.member_id; |
As always, I look forward to helping and gaining insight.
Debugging MySQL Functions
Somebody, who read this post on Debugging MySQL Procedures, asked why the strategy of selecting a string literal didn’t work in a MySQL function. That’s easy, they’re not designed to support a SELECT
statement, only a SELECT-INTO
statement.
Why? That’s the purpose of a function to perform something and return a single reply.
That’s also why a MySQL functions only support the IN
mode of operation for formal and call parameters. When formal parameters are restricted to in-mode-only operations, they implement a pass-by-value function model. This can also be expressed from the other side of the looking glass. In that case, MySQL functions don’t support pass-by-reference functions that use the INOUT
or OUT
mode operations.
If you put a SELECT
statement in a function to print internal values or comments, it raises an error. Take for example the following attempt to create the debugging
function with an echo of output (that works in stored procedures).
CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT '[Debug #1]'; RETURN 1; END; $$ |
It fails to create the function because you’ve violated a key integrity rule. It also raises the following error:
ERROR 1415 (0A000): Not allowed to return a result set from a function |
You have two potential solutions to this problem. The first is limited and inflexible. The second isn’t as limited or inflexible and is the recommended way to debug your functions without a tool. That’s to use a temporary table to record run-time debugging events.
Session Variable Debugging ↓
Expand this section to see the steps for debugging functions with session variables.
- Create two session level variables, like these:
SET @counter := 0; SET @msg := ''; |
- Create a function that uses the
SELECT-INTO
statement to collect and store debugging information during function execution.
CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT @counter + 1 INTO @counter; SELECT CONCAT('[Debug #',@counter,']') INTO @msg; RETURN 1; END; $$ |
- Run the function and then query the session variable for results
SELECT debugger(); SELECT @msg; |
You’ll see the following text:
+------------+ | @msg | +------------+ | [Debug #1] | +------------+ |
Temporary Table Debugging ↓
Expand this section to see the steps for debugging functions with session variables.
- Only when you want a counter, create one session level variables.
SET @counter := 0; |
- Create an in-memory table to store debugging information from function execution.
CREATE TABLE debugger ( debug_comment CHAR(80)) ENGINE=MEMORY; |
- Create a function that supports inserts into the in-memory table. Naturally, you may need to make the columns larger when your debugging results are large. I’ve found that 80 characters is generally adequate for most debugging exercises.
1 2 3 4 5 6 7 | CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT @counter + 1 INTO @counter; INSERT INTO debugger VALUES (CONCAT('[Debug #',@counter,']')); RETURN 1; END; $$ |
- Call the function and query the debugging results.
SELECT debugger(); SELECT debugger(); SELECT debugger(); SELECT debug_comment FROM debugger; |
You’ll see the following text:
+---------------+ | debug_comment | +---------------+ | [Debug #1] | | [Debug #2] | | [Debug #3] | +---------------+ |
Complete Code Sample ↓
Expand this section to see the sample working code for all examples.
This script creates, runs, and tests the code from the above discussions.
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 | -- Conditionally drop the function when it exists. DROP FUNCTION IF EXISTS debugger; -- Set delimiter to create a function with semicolon statment terminators. DELIMITER $$ -- Create a function that returns 1. CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT '[Debug #1]'; RETURN 1; END; $$ -- Reset the delimiter to enable normal execution. DELIMITER ; -- Declare session level variables. SET @counter := 0; SET @msg := ''; -- Conditionally drop the function when it exists. DROP FUNCTION IF EXISTS debugger; -- Set delimiter to create a function with semicolon statment terminators. DELIMITER $$ -- Create a function that writes to local session variables. CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT @counter + 1 INTO @counter; SELECT CONCAT('[Debug #',@counter,']') INTO @msg; RETURN 1; END; $$ -- Reset the delimiter to enable normal execution. DELIMITER ; -- Test the function code and read the session-level variable contents. SELECT debugger(); SELECT @msg; -- Declare a session level variable. SET @counter := 0; -- Conditionally drop the function when it exists. DROP TABLE IF EXISTS debugger; -- Create a temporary (in-memory) table to record debugging information. CREATE TABLE debugger ( debug_comment CHAR(80)) ENGINE=MEMORY; -- Conditionally drop the function when it exists. DROP FUNCTION IF EXISTS debugger; -- Set delimiter to create a function with semicolon statment terminators. DELIMITER $$ -- Create a function that writes to a debugging table. CREATE FUNCTION debugger() RETURNS INT BEGIN SELECT @counter + 1 INTO @counter; INSERT INTO debugger VALUES (CONCAT('[Debug #',@counter,']')); RETURN 1; END; $$ -- Reset the delimiter to enable normal execution. DELIMITER ; -- Test the function code and read the session-level variable contents. SELECT debugger(); SELECT debugger(); SELECT debugger(); SELECT debug_comment FROM debugger; |
Show indexes in Oracle
One of my students asked how you could show index from table_name;
in Oracle. They were chagrined when I told them there wasn’t an equivalent command. Outside of using Quest’s Toad or Oracle SQL*Developer, you can query the data catalog, like so:
-- SQL*Plus formatting commands. COLUMN index_name FORMAT A32 COLUMN column_position FORMAT 999 HEADING "COLUMN|POSITION" COLUMN column_name FORMAT A32 -- Ordinary query with a substitution variable. SELECT i.index_name , ic.column_position , ic.column_name FROM user_indexes i JOIN user_ind_columns ic ON i.index_name = ic.index_name WHERE i.table_name = UPPER('&input') |
Naturally, this is a subset of what’s returned by the show index from table_name
; syntax. There is much more information in these tables but I only wanted to show an example.
The UPPER
function command ensures that the table name is found in the database. Unless you’ve created a case sensitive object, they’re stored in uppercase strings.
While a single SQL statement works well, a little organization in PL/SQL makes it more readable. A display_indexes
function provides that organization. It only displays normal indexes, not LOB indexes, and it depends on a schema-level collection of strings. This is the user-defined type (UDT) that I used for the collection.
CREATE OR REPLACE TYPE index_table AS TABLE OF VARCHAR2(200); / |
The following is the definition of the 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 | CREATE OR REPLACE FUNCTION display_indexes ( pv_table_name VARCHAR2 ) RETURN INDEX_TABLE IS -- Declare an iterator for the collection return variable. index_counter NUMBER := 1; column_counter NUMBER; -- Declare and initialize local collection variable as return type. index_desc INDEX_TABLE := index_table(); -- Get indexes. CURSOR index_name (cv_table_name VARCHAR2) IS SELECT i.index_name FROM user_indexes i WHERE i.table_name = cv_table_name AND i.index_type = 'NORMAL' ORDER BY 1; -- Get index columns. CURSOR index_columns (cv_index_name VARCHAR2) IS SELECT ic.column_position , ic.column_name FROM user_ind_columns ic WHERE ic.index_name = cv_index_name ORDER BY 1; BEGIN -- Assign the table name to the collection. index_desc.EXTEND; index_desc(index_counter) := UPPER(pv_table_name); index_counter := index_counter + 1; FOR i IN index_name(UPPER(pv_table_name)) LOOP -- Assign the index name to the collection. index_desc.EXTEND; index_desc(index_counter) := LPAD(i.index_name,2 + LENGTH(i.index_name),' '); -- Set column counter on entry to nested loop. column_counter := 1; FOR j IN index_columns(i.index_name) LOOP IF column_counter = 1 THEN -- Increment the column counter, extend space, and concatenate to string. column_counter := column_counter + 1; index_desc.EXTEND; index_desc(index_counter) := index_desc(index_counter) || '(' || LOWER(j.column_name); ELSE -- Add a subsequent column to the list. index_desc(index_counter) := index_desc(index_counter) || ',' || LOWER(j.column_name); END IF; END LOOP; -- Append a close parenthesis and incredment index counter. index_desc(index_counter) := index_desc(index_counter) || ')'; index_counter := index_counter + 1; END LOOP; -- Return the array. RETURN index_desc; END; / |
You can call the function with this syntax:
SELECT column_value AS "TRANSACTION INDEXES" FROM TABLE(display_indexes('TRANSACTION')); |
It returns the following formatted output for the TRANSACTION
table, which is much nicer than the SQL output. Unfortunately, it will take more effort to place it on par with the show index from table_name;
in MySQL.
TRANSACTION INDEXES ------------------------------------------------------------------------------------------------------------------------------ TRANSACTION PK_TRANSACTION(transaction_id) UQ_TRANSACTION(rental_id,transaction_type,transaction_date,payment_method_type,payment_account_number,transaction_account) |
As always, I hope it helps folks.
A \G Option for Oracle?
The \G
option in MySQL lets you display rows of data as sets with the columns on the left and the data on the write. I figured it would be fun to write those for Oracle when somebody pointed out that they weren’t out there in cyberspace (first page of a Google search ;-)).
I started the program with a student’s code. I thought it a bit advanced for the student but didn’t check if he’d snagged it somewhere. Thanks to Niall Litchfield, I now know that the base code came from an earlier post of Tom Kyte. Tom’s example code failed when returning a Blob, BFile, or CFile column.
Naturally, there are two ways to write this. One is a procedure and the other is the function. This post contains both. The procedure is limited because of potential buffer overflows associated with the DBMS_OUTPUT
package’s display. A function isn’t limited because you can return a collection from the function.
Required setup to use the DBMS_SQL
package ↓
The DBMS_SQL
package requires permissions. There are two ways to provide those permissions. One is more secure and sensible in a production system and the other is great in a development test system.
Production or Test System
If this is a production system, you probably want to grant permissions only to the SYSTEM
schema. This follows the practice of narrowing access to powerful features and control systems.
The first step requires the SYS
user to grant permissions and authority to re-grant to individual users. You connect as the privileged user, like:
sqlplus / AS sysdba |
When connected as the SYS
, you run the following two commands:
GRANT EXECUTE ON dbms_sys_sql TO system; GRANT EXECUTE ON dbms_sql TO system; |
You should then define the procedure or function as a CURRENT_USER
module. This type of module is known as an invoker’s right program. The code is owned by the SYSTEM
schema but you run it on your own objects in your less privileged schema.
You can do that by replacing the function and procedure headers with these:
CREATE OR REPLACE PROCEDURE display_vertical ( TABLE_NAME VARCHAR2, where_clause VARCHAR2 ) AUTHID CURRENT_USER IS |
CREATE OR REPLACE FUNCTION vertical_query ( TABLE_NAME VARCHAR2, where_clause VARCHAR2 ) RETURN query_result AUTHID CURRENT_USER IS |
After you compile the procedure and function in the SYSTEM
schema, you should grant access to a schema (more restricted) or public (as generic tools). You should also create synonyms. The following commands assume you want to deploy these as generic tools. As the SYSTEM
user, it grants privileges and then creates public synonyms.
-- Grant privileges. GRANT EXECUTE ON display_vertical TO PUBLIC; GRANT EXECUTE ON vertical_query TO PUBLIC; -- Create public synonyms. CREATE PUBLIC SYNONYM display_vertical FOR system.display_vertical; CREATE PUBLIC SYNONYM vertical_query FOR system.vertical_query; |
You should now be able to call these from any schema to work with their own tables and views.
Student Development System
If this is a test system and you’re new to Oracle, the following should help you. This shows you how to implement these in a Definer’s right model, inside a STUDENT
schema.
This isn’t a secure design, but it allows you to keep your testing limited to a STUDENT
schema. When these permissions aren’t granted the examples won’t work at all.
The first step requires the SYS
user to grant permissions and authority to re-grant to individual users. You connect as the privileged user, like:
sqlplus / AS sysdba |
When connected as the SYS
, you run the following two commands:
GRANT EXECUTE ON dbms_sys_sql TO system WITH GRANT OPTION; GRANT EXECUTE ON dbms_sql TO system WITH GRANT OPTION; |
You don’t have to exit to reconnect as the SYSTEM
user. Just type the following at the SQL
command prompt (substitute your password ;-)).
CONNECT system/password |
When connected as the SYSTEM
user, you run the following two commands:
GRANT EXECUTE ON dbms_sys_sql TO student; GRANT EXECUTE ON dbms_sql TO student; |
You should now be able to compile the function and procedure.
Procedure for \G
output ↓
The procedure nice because there’s only a dependency on the buffer size for the DBMS_OUTPUT
package. The procedure only returns column values that are printable at the console, and it only returns the first 40 characters of long text strings.
Here’s the procedure definition:
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 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 | -- Create procedure. CREATE OR REPLACE PROCEDURE display_vertical ( TABLE_NAME VARCHAR2, where_clause VARCHAR2 ) IS -- Open a cursor for a query against all columns in a table. base_stmt INTEGER := dbms_sql.open_cursor; -- Open a cursor for a dynamically constructed query, which excludes -- any non-displayable columns with text. stmt INTEGER := dbms_sql.open_cursor; -- Declare local variables. colValue VARCHAR2(4000); -- Declare a maximum string length for column values. STATUS INTEGER; -- Declare a variable to hold acknowledgement of DBMS_SQL.EXECUTE tableDesc dbms_sql.desc_tab2; -- Declare a table to hold metadata for the queries. colCount NUMBER; -- Declare a variable for the column count. rowIndex NUMBER := 0; -- for displaying the row number retrieved from the cursor colLength NUMBER := 0; -- for keeping track of the length of the longest column name -- Declare local variable for the dynamically constructed query. dynamic_stmt VARCHAR2(4000) := 'SELECT '; -- Declare an exception for a bad table name, raised by a call to -- the dbms_assert.qualified_sql_name function. table_name_error EXCEPTION; PRAGMA EXCEPTION_INIT(table_name_error, -942); -- Declare exception handlers for bad WHERE clause statements. -- Declare an exception for a missing WHERE keyword. missing_keyword EXCEPTION; PRAGMA EXCEPTION_INIT(missing_keyword, -933); -- Declare an exception for a bad relational operator. invalid_relational_operator EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_relational_operator, -920); -- Declare an exception for a bad column name. invalid_identifier EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_identifier, -904); -- Declare an exception for a missing backquoted apostrophe. misquoted_string EXCEPTION; PRAGMA EXCEPTION_INIT(misquoted_string, -1756); -- Declare a function that replaces non-displayable values with text messages. FUNCTION check_column( p_name VARCHAR2 , p_type NUMBER ) RETURN VARCHAR2 IS -- Return column name or literal value. retval VARCHAR2(30); BEGIN -- Find strings, numbers, dates, timestamps, rowids and replace non-display values. IF p_type IN (1,2,8,9,12,69,96,100,101,112,178,179,180,181,231) THEN -- Assign the column name for a displayable column value. retval := p_name; ELSE -- Re-assign string literals for column names where values aren't displayable. SELECT DECODE(p_type, 23,'''RAW not displayable.''' ,105,'''MLSLABEL not displayable.''' ,106,'''MLSLABEL not displayable.''' ,113,'''BLOB not displayable.''' ,114,'''BFILE not displayable.''' ,115,'''CFILE not displayable.''' ,'''UNDEFINED not displayable.''') INTO retval FROM dual; END IF; -- Return the column name or a apostrophe delimited string literal. RETURN retval; END check_column; BEGIN -- Prepare unfiltered display cursor. dbms_sql.parse(base_stmt, 'SELECT * FROM ' || dbms_assert.simple_sql_name(TABLE_NAME) || ' ' || where_clause, dbms_sql.native); -- Describe the table structure: -- -------------------------------------------------------- -- 1. Store metadata in tableDesc -- 2. Store the number of columns in colCount -- -------------------------------------------------------- dbms_sql.describe_columns2(base_stmt, colCount, tableDesc); -- Define individual columns and assign value to colValue variable. FOR i IN 1..colCount LOOP -- Define columns for each column returned into tableDesc. dbms_sql.define_column(base_stmt, i, colValue, 4000); -- Find the length of the longest column name. IF LENGTH(tableDesc(i).col_name) > colLength THEN colLength := LENGTH(tableDesc(i).col_name); END IF; -- Replace non-displayable column values with displayable values. IF i < colCount THEN dynamic_stmt := dynamic_stmt || check_column(tableDesc(i).col_name,tableDesc(i).col_type) || ' AS ' || tableDesc(i).col_name || ', '; ELSE dynamic_stmt := dynamic_stmt || check_column(tableDesc(i).col_name,tableDesc(i).col_type) || ' AS ' || tableDesc(i).col_name || ' ' || 'FROM ' || dbms_assert.simple_sql_name(TABLE_NAME) || ' ' || where_clause; END IF; END LOOP; -- Provide conditional debugging instruction that displays dynamically created query. $IF $$DEBUG = 1 $THEN dbms_output.put_line(dynamic_stmt); $END -- Prepare unfiltered display cursor. dbms_sql.parse(stmt, dynamic_stmt, dbms_sql.native); -- Describe the table structure: -- -------------------------------------------------------- -- 1. Store metadata in tableDesc (reuse of existing variable) -- 2. Store the number of columns in colCount -- -------------------------------------------------------- dbms_sql.describe_columns2(stmt, colCount, tableDesc); -- Define individual columns and assign value to colValue variable. FOR i IN 1..colCount LOOP dbms_sql.define_column(stmt, i, colValue, 4000); END LOOP; -- Execute the dynamic cursor. STATUS := dbms_sql.execute(stmt); -- Fetch the results, row-by-row. WHILE dbms_sql.fetch_rows(stmt) > 0 LOOP -- Reset row counter for display purposes. rowIndex := rowIndex + 1; dbms_output.put_line('********************************** ' || rowIndex || '. row **********************************'); -- For each column, print left-aligned column names and values. FOR i IN 1..colCount LOOP -- Limit display of long text. IF tableDesc(i).col_type IN (1,9,96,112) THEN -- Display 40 character substrings of long text. dbms_sql.column_value(stmt, i, colValue); dbms_output.put_line(RPAD(tableDesc(i).col_name, colLength,' ') || ' : ' || SUBSTR(colValue, 1,40)); ELSE -- Display full value as character string. dbms_sql.column_value(stmt, i, colValue); dbms_output.put_line(RPAD(tableDesc(i).col_name, colLength,' ') || ' : ' || colValue); END IF; END LOOP; END LOOP; EXCEPTION -- Customer error handlers. WHEN table_name_error THEN dbms_output.put_line(SQLERRM); WHEN invalid_relational_operator THEN dbms_output.put_line(SQLERRM); WHEN invalid_identifier THEN dbms_output.put_line(SQLERRM); WHEN missing_keyword THEN dbms_output.put_line(SQLERRM); WHEN misquoted_string THEN dbms_output.put_line(SQLERRM); WHEN OTHERS THEN dbms_output.put_line(SQLERRM); END; / |
You can run the procedure with the following syntax:
EXECUTE display_vertical('ITEM','WHERE item_title LIKE ''Star%'''); |
It’ll return the following display of data:
********************************** 1. ROW ********************************** ITEM_ID : 1002 ITEM_BARCODE : 24543-02392 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars I ITEM_SUBTITLE : Phantom Menace ITEM_RATING : PG ITEM_RELEASE_DATE : 04-MAY-99 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 2. ROW ********************************** ITEM_ID : 1003 ITEM_BARCODE : 24543-5615 ITEM_TYPE : 1010 ITEM_TITLE : Star Wars II ITEM_SUBTITLE : Attack OF the Clones ITEM_RATING : PG ITEM_RELEASE_DATE : 16-MAY-02 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 3. ROW ********************************** ITEM_ID : 1004 ITEM_BARCODE : 24543-05539 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars II ITEM_SUBTITLE : Attack OF the Clones ITEM_RATING : PG ITEM_RELEASE_DATE : 16-MAY-02 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : This IS designed TO be a long enough str DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 4. ROW ********************************** ITEM_ID : 1005 ITEM_BARCODE : 24543-20309 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars III ITEM_SUBTITLE : Revenge OF the Sith ITEM_RATING : PG13 ITEM_RELEASE_DATE : 19-MAY-05 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. |
Function for \G
output ↓
The function is the best solution. It does have a dependency on a user-defined type (UDT). The function, like the procedure, only returns column values that are printable at the console. It also parses the first 40 characters from long text strings.
Before you create the function, you must create a UDT collection variable. The following syntax creates a schema-level UDT.
CREATE OR REPLACE TYPE query_result AS TABLE OF VARCHAR2(77); / |
Here’s the function definition:
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 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 | CREATE OR REPLACE FUNCTION vertical_query ( TABLE_NAME VARCHAR2, where_clause VARCHAR2 ) RETURN query_result IS -- Open a cursor for a query against all columns in a table. base_stmt INTEGER := dbms_sql.open_cursor; -- Open a cursor for a dynamically constructed query, which excludes -- any non-displayable columns with text. stmt INTEGER := dbms_sql.open_cursor; -- Declare local variables. colValue VARCHAR2(4000); -- Declare a maximum string length for column values. STATUS INTEGER; -- Declare a variable to hold acknowledgement of DBMS_SQL.EXECUTE tableDesc dbms_sql.desc_tab2; -- Declare a table to hold metadata for the queries. colCount NUMBER; -- Declare a variable for the column count. rowIndex NUMBER := 0; -- for displaying the row number retrieved from the cursor colLength NUMBER := 0; -- for keeping track of the length of the longest column name -- Declare local variable for the dynamically constructed query. dynamic_stmt VARCHAR2(4000) := 'SELECT '; -- Declare a index for the return collection. rsIndex NUMBER := 0; -- Declare a collection variable and instantiate the collection. result_set QUERY_RESULT := query_result(); -- Declare an exception for a bad table name, raised by a call to -- the dbms_assert.qualified_sql_name function. table_name_error EXCEPTION; PRAGMA EXCEPTION_INIT(table_name_error, -942); -- Declare exception handlers for bad WHERE clause statements. -- Declare an exception for a missing WHERE keyword. missing_keyword EXCEPTION; PRAGMA EXCEPTION_INIT(missing_keyword, -933); -- Declare an exception for a bad relational operator. invalid_relational_operator EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_relational_operator, -920); -- Declare an exception for a bad column name. invalid_identifier EXCEPTION; PRAGMA EXCEPTION_INIT(invalid_identifier, -904); -- Declare an exception for a missing backquoted apostrophe. misquoted_string EXCEPTION; PRAGMA EXCEPTION_INIT(misquoted_string, -1756); -- ------------------------------------------------------------------ -- Declare a function that replaces non-displayable values with text messages. FUNCTION check_column( p_name VARCHAR2 , p_type NUMBER ) RETURN VARCHAR2 IS -- Return column name or literal value. retval VARCHAR2(30); BEGIN -- Find strings, numbers, dates, timestamps, rowids and replace non-display values. IF p_type IN (1,2,8,9,12,69,96,100,101,112,178,179,180,181,231) THEN -- Assign the column name for a displayable column value. retval := p_name; ELSE -- Re-assign string literals for column names where values aren't displayable. SELECT DECODE(p_type, 23,'''RAW not displayable.''' ,105,'''MLSLABEL not displayable.''' ,106,'''MLSLABEL not displayable.''' ,113,'''BLOB not displayable.''' ,114,'''BFILE not displayable.''' ,115,'''CFILE not displayable.''' ,'''UNDEFINED not displayable.''') INTO retval FROM dual; END IF; -- Return the column name or a apostrophe delimited string literal. RETURN retval; END check_column; -- ------------------------------------------------------------------ BEGIN -- Prepare unfiltered display cursor. dbms_sql.parse(base_stmt, 'SELECT * FROM ' || dbms_assert.simple_sql_name(TABLE_NAME) || ' ' || where_clause, dbms_sql.native); -- Describe the table structure: -- -------------------------------------------------------- -- 1. Store metadata in tableDesc -- 2. Store the number of columns in colCount -- -------------------------------------------------------- dbms_sql.describe_columns2(base_stmt, colCount, tableDesc); -- Define individual columns and assign value to colValue variable. FOR i IN 1..colCount LOOP -- Define columns for each column returned into tableDesc. dbms_sql.define_column(base_stmt, i, colValue, 4000); -- Find the length of the longest column name. IF LENGTH(tableDesc(i).col_name) > colLength THEN colLength := LENGTH(tableDesc(i).col_name); END IF; -- Replace non-displayable column values with displayable values. IF i < colCount THEN dynamic_stmt := dynamic_stmt || check_column(tableDesc(i).col_name,tableDesc(i).col_type) || ' AS ' || tableDesc(i).col_name || ', '; ELSE dynamic_stmt := dynamic_stmt || check_column(tableDesc(i).col_name,tableDesc(i).col_type) || ' AS ' || tableDesc(i).col_name || ' ' || 'FROM ' || dbms_assert.simple_sql_name(TABLE_NAME) || ' ' || where_clause; END IF; END LOOP; -- Provide conditional debugging instruction that displays dynamically created query. $IF $$DEBUG = 1 $THEN dbms_output.put_line(dynamic_stmt); $END -- Prepare unfiltered display cursor. dbms_sql.parse(stmt, dynamic_stmt, dbms_sql.native); -- Describe the table structure: -- -------------------------------------------------------- -- 1. Store metadata in tableDesc (reuse of existing variable) -- 2. Store the number of columns in colCount -- -------------------------------------------------------- dbms_sql.describe_columns2(stmt, colCount, tableDesc); -- Define individual columns and assign value to colValue variable. FOR i IN 1..colCount LOOP dbms_sql.define_column(stmt, i, colValue, 4000); END LOOP; -- Execute the dynamic cursor. STATUS := dbms_sql.execute(stmt); -- Fetch the results, row-by-row. WHILE dbms_sql.fetch_rows(stmt) > 0 LOOP -- Reset row counter for output display purposes. rowIndex := rowIndex + 1; -- Increment the counter for the collection and extend space before assignment. rsIndex := rsIndex + 1; result_set.EXTEND; result_set(rsIndex) := '********************************** ' || rowIndex || '. row **********************************'; -- For each column, print left-aligned column names and values. FOR i IN 1..colCount LOOP -- Increment the counter for the collection and extend space before assignment. rsIndex := rsIndex + 1; result_set.EXTEND; -- Limit display of long text. IF tableDesc(i).col_type IN (1,9,96,112) THEN -- Display 40 character substrings of long text. dbms_sql.column_value(stmt, i, colValue); result_set(rsIndex) := RPAD(tableDesc(i).col_name, colLength,' ') || ' : ' || SUBSTR(colValue, 1,40); ELSE -- Display full value as character string. dbms_sql.column_value(stmt, i, colValue); result_set(rsIndex) := RPAD(tableDesc(i).col_name, colLength,' ') || ' : ' || colValue; END IF; END LOOP; END LOOP; -- Increment the counter for the collection and extend space before assignment. FOR i IN 1..3 LOOP rsIndex := rsIndex + 1; result_set.EXTEND; CASE i WHEN 1 THEN result_set(rsIndex) := '****************************************************************************'; WHEN 2 THEN result_set(rsIndex) := CHR(10); WHEN 3 THEN result_set(rsIndex) := rowIndex || ' rows in set'; END CASE; END LOOP; -- Return collection. RETURN result_set; EXCEPTION -- Customer error handlers, add specialized text or collapse into one with the OTHERS catchall. WHEN table_name_error THEN dbms_output.put_line(SQLERRM); WHEN invalid_relational_operator THEN dbms_output.put_line(SQLERRM); WHEN invalid_identifier THEN dbms_output.put_line(SQLERRM); WHEN missing_keyword THEN dbms_output.put_line(SQLERRM); WHEN misquoted_string THEN dbms_output.put_line(SQLERRM); WHEN OTHERS THEN dbms_output.put_line(SQLERRM); END; / |
Before you attempt to run the function, you should set two Oracle SQL*Plus environment commands. One suppresses a message saying what just ran, and the other removes column headers. Clearly, the output is sufficient and the headers are clutter. You set these, as noted below:
SET FEEDBACK OFF SET PAGESIZE 0 |
You can run the function with the following syntax (the COLUMN_VALUE
is the standard name returned from a scalar schema-level collection.
SELECT column_value FROM TABLE(vertical_query('ITEM','WHERE item_title LIKE ''Star%''')); |
It’ll return the following display of data:
********************************** 1. ROW ********************************** ITEM_ID : 1002 ITEM_BARCODE : 24543-02392 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars I ITEM_SUBTITLE : Phantom Menace ITEM_RATING : PG ITEM_RELEASE_DATE : 04-MAY-99 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 2. ROW ********************************** ITEM_ID : 1003 ITEM_BARCODE : 24543-5615 ITEM_TYPE : 1010 ITEM_TITLE : Star Wars II ITEM_SUBTITLE : Attack OF the Clones ITEM_RATING : PG ITEM_RELEASE_DATE : 16-MAY-02 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 3. ROW ********************************** ITEM_ID : 1004 ITEM_BARCODE : 24543-05539 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars II ITEM_SUBTITLE : Attack OF the Clones ITEM_RATING : PG ITEM_RELEASE_DATE : 16-MAY-02 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : This IS designed TO be a long enough str DISPLAY_PHOTO : BLOB NOT displayable. ********************************** 4. ROW ********************************** ITEM_ID : 1005 ITEM_BARCODE : 24543-20309 ITEM_TYPE : 1011 ITEM_TITLE : Star Wars III ITEM_SUBTITLE : Revenge OF the Sith ITEM_RATING : PG13 ITEM_RELEASE_DATE : 19-MAY-05 CREATED_BY : 3 CREATION_DATE : 09-JUN-10 LAST_UPDATED_BY : 3 LAST_UPDATE_DATE : 09-JUN-10 ITEM_DESC : DISPLAY_PHOTO : BLOB NOT displayable. **************************************************************************** |
As usual, I hope this helps folks.
A couple DBMS_SQL limits
While developing a dynamic SQL example in Oracle 11g that builds a query based on available display columns, I found two interesting error messages. Now instead of noting it for the umpteenth time, I’m documenting it for everybody. The error messages are generated when this DBMS_SQL
package’s statement is a SELECT
statement, and is executed with either a BLOB
, BFILE
or CFILE
column in the list of returned columns.
26 | STATUS := dbms_sql.execute(stmt); |
BLOB
data type
You get the following error when a column in the query has a BLOB
data type. If you alter the query to exclude the column, no error occurs.
BEGIN test('DEMO'); END; * ERROR at line 1: ORA-00932: inconsistent datatypes: expected NUMBER got BLOB ORA-06512: at "SYS.DBMS_SQL", line 1575 ORA-06512: at "STUDENT.TEST", line 26 ORA-06512: at line 1 |
BFILE
or CFILE
data type
You get the following error when a column in the query has a BFILE
or CFILE
data type. If you alter the query to exclude the column, no error occurs.
BEGIN test('DEMO'); END; * ERROR at line 1: ORA-00932: inconsistent datatypes: expected NUMBER got FILE ORA-06512: at "SYS.DBMS_SQL", line 1575 ORA-06512: at "STUDENT.TEST", line 26 ORA-06512: at line 1 |
It’s never a joy to debug the DBMS_SQL
package, at least it’s never a joy for me. I hope this helps somebody sort out an issue more quickly.
Oracle Trigger on Merge
An interesting question came up today while discussing PL/SQL database triggers. Could you create a trigger on a MERGE
statement, like this:
1 2 3 4 5 6 7 8 | CREATE OR REPLACE TRIGGER contact_merge_t1 BEFORE MERGE OF last_name ON contact_merge FOR EACH ROW WHEN (REGEXP_LIKE(NEW.last_name,' ')) BEGIN :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); END contact_merge_t1; / |
The answer is, no you can’t. It’ll raise an ORA-04073
error if you attempt it, like this:
BEFORE MERGE OF last_name ON contact * ERROR at line 2: ORA-04073: COLUMN list NOT valid FOR this TRIGGER TYPE |
The only supported DML events are INSERT
, UPDATE
, and DELETE
. The following DML trigger works against a MERGE
statement. After all a MERGE
statement is nothing more than an INSERT
or UPDATE
statement.
1 2 3 4 5 6 7 8 | CREATE OR REPLACE TRIGGER contact_merge_t1 BEFORE INSERT OR UPDATE OF last_name ON contact_merge FOR EACH ROW WHEN (REGEXP_LIKE(NEW.last_name,' ')) BEGIN :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); END contact_merge_t1; / |
Complete Code Sample ↓
Expand this section to see the sample working code.
This script creates a CONTACT
table, a row-level TRIGGER
, a MERGE
statement, and query to display the 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 | -- Conditionally drop the table. BEGIN FOR i IN (SELECT NULL FROM user_tables WHERE TABLE_NAME = 'CONTACT_MERGE') LOOP EXECUTE IMMEDIATE 'DROP TABLE contact_merge'; END LOOP; END; / -- Create the table. CREATE TABLE contact_merge ( contact_id NUMBER , member_id NUMBER NOT NULL , contact_type NUMBER NOT NULL , first_name VARCHAR2(20) NOT NULL , middle_name VARCHAR2(20) , last_name VARCHAR2(20) NOT NULL , created_by NUMBER NOT NULL , creation_date DATE NOT NULL , last_updated_by NUMBER NOT NULL , last_update_date DATE , CONSTRAINT contact_merge_pk PRIMARY KEY(contact_id)); -- Create the trigger to enforce hyphenated last names.. CREATE OR REPLACE TRIGGER contact_merge_t1 BEFORE INSERT OR UPDATE OF last_name ON contact_merge FOR EACH ROW WHEN (REGEXP_LIKE(NEW.last_name,' ')) BEGIN :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); END contact_merge_t1; / -- Merge statement that violates business rule. MERGE INTO contact_merge target USING ( SELECT 2001 AS contact_id , 1001 AS member_id , 1001 AS contact_type ,'Catherine' AS first_name ,'' AS middle_name ,'Zeta Jones' AS last_name , 2 AS created_by , SYSDATE AS creation_date , 2 AS last_updated_by , SYSDATE AS last_update_date FROM dual) SOURCE ON (target.contact_id = SOURCE.contact_id) WHEN MATCHED THEN UPDATE SET target.last_updated_by = 3 WHEN NOT MATCHED THEN INSERT VALUES ( SOURCE.contact_id , SOURCE.member_id , SOURCE.contact_type , SOURCE.first_name , SOURCE.middle_name , SOURCE.last_name , SOURCE.created_by , SOURCE.creation_date , SOURCE.last_updated_by , SOURCE.last_update_date ); -- Query results. SELECT first_name||DECODE(middle_name,NULL,' ',' '||middle_name||' ')||last_name AS full_name FROM contact_merge WHERE first_name = 'Catherine'; |
Alice and Assignments
As I continue down the warren hole of Persistent Stored Modules (SQL/PSM) in MySQL, I keep wondering about that mad hare, Johnny Depp. Alice isn’t a programming language to teach me anything in this dream. Moreover, TIm Burton’s tale this seems oddly familiar, like a child’s story gone mad.
A quick update on comparative SQL expression assignments between PL/SQL and MySQL. When you want to filter a value through SQL functions before assigning it to another variable in MySQL, it’s not like PL/SQL. Just like the new Alice in Wonderland movie isn’t like the book.
The programmatic differences lies in their origins. PL/SQL evolved from Pascal through Ada to become a recursive language where you can call SQL from PL/SQL and PL/SQL from SQL. MySQL implemented PSMs from the ANSI SQL:2003 specification, which didn’t see it the same way, apparently (a disclaimer since I’ve not read the details of the specification).
Personally, I think PL/SQL is easier to write but I’ve been using it for almost 20 years. Naturally, there may be a consistency thread on this that I’m missing and an opportunity that I may exploit. After all, it is dark in this warren hole.
Oracle PL/SQL Assignments from SQL Expressions
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 | -- Enable output printing. SET SERVEROUTPUT ON SIZE 1000000 -- Define an anonymous block. DECLARE -- Declare a source variable. lv_right_operand VARCHAR2(10) := 'March'; -- Define a target variable for the assignment. lv_left_operand VARCHAR2(10); BEGIN -- Return the expression from a nested call parameter of the source variable. lv_left_operand := UPPER(SUBSTR(lv_right_operand,1,3)); -- Print it to console. dbms_output.put_line('Output ['||lv_left_operand||']'); END; / |
Oracle also supports this syntax, which isn’t frequently used because it’s much more verbose syntactically. It is also equivalent to the PSM syntax adopted by MySQL.
-- Define an anonymous block. DECLARE -- Declare a source variable. lv_right_operand VARCHAR2(10) := 'March'; -- Define a target variable for the assignment. lv_left_operand VARCHAR2(10); BEGIN -- Return the expression from a nested call parameter of the source variable. SELECT UPPER(SUBSTR(lv_right_operand,1,3)) INTO lv_left_operand FROM dual; -- Print it to console. dbms_output.put_line('Output ['||lv_left_operand||']'); END; / |
That means we can do it like the White Queen wants it or the Red Queen wants it in Oracle. Flexibility in PL/SQL is clearly broader because of the assignment options. Not so in MySQL, as you’ll see.
MySQL PSM Assignment from SQL Expressions
First, MySQL’s PSM approach doesn’t support anonymous blocks. The example must create a stored function or procedure, and then call it. A procedure seems like the best fit for the example.
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 | -- Conditionally drop procedure. SELECT 'DROP PROCEDURE IF EXISTS assignit' AS "Statement"; DROP PROCEDURE IF EXISTS assignit; -- Create the proceudre SELECT 'CREATE PROCEDURE assignit' AS "Statement"; DELIMITER $$ -- Define the procedure. CREATE PROCEDURE assignit() BEGIN /* Declare a source variable. */ DECLARE lv_right_operand VARCHAR(10) DEFAULT 'March'; /* Define a target variable for the assignment. */ DECLARE lv_left_operand VARCHAR(3); /* Assign the modified value through the SELECT-INTO model. */ SELECT UCASE(SUBSTRING(lv_right_operand,1,3)) INTO lv_left_operand; /* Display assigned value. */ SELECT lv_left_operand; END; $$ DELIMITER ; -- Call the procedure. CALL assignit(); |
The only question here in the warren is: Who’s the White Queen; and who’s the Red Queen. Which semantic should I choose? My I hope is that I wake up before it’s … oops, off with his head. Actually, 3D or not, I’ll probably not see it, that’s the new Alice in Wonderland film.
Likewise, when my students wake up and read this they’ll know I was just answering a question on how to perform assignments in MySQL stored procedures. By the way, I’ve updated this assignment process in my Debugging MySQL Procedures post.
As an aside, I’ve got a new MySQL debugger that I’m testing later in the week. When I complete the test cases, I’ll post a review.
Wrap a cursor function
A Gauss posted a question on my from last year’s Utah Oracle User’s Group Training Days presentation. If I understood his question correctly, this should help him work with his legacy code. Honestly, as I wrote the example something Bryn Llewellyn said kept banging around in my head, “Just because we can, doesn’t mean we should.” He was speaking of writing poorly engineered code.
Sometimes, we don’t get the opportunity to re-factor existing code. That leaves us with writing wrappers that aren’t pretty or effective. A realization and preface to showing everyone how to accomplish these tasks, and perhaps a watch out warning if you choose this path. I suspect that there may be a better way but I don’t know their code tree.
Here’s the question, as I understand it. They’ve got a library function in PL/SQL that returns a system reference cursor and is principally consumed by an external Java program. This type of architecture is more or less an Adapter OOAD pattern that I wrote about here, over a year and a half ago. The question comes to how to you wrap this approach and make it work in PL/SQL natively too.
The answer depends on some earlier posts because I don’t have a great deal of time to write new examples. It uses a COMMON_LOOKUP
table, which is more or less a bunch of small tables grouped into a big table for use in user interaction forms. That way the values don’t get lost in a large code base and are always consistently maintained. These types of tables exist in all major ERP and CRM applications.
The base code for the example is found here, where I discussed how you can effectively use object tables – collections of user-defined object types (Oracle 9iR2 forward if I remember correctly). You can grab the full code at the bottom of the page by clicking the Code Script widget to unfold the code. That code also depends on the Oracle Database 11g PL/SQL Programming downloadable code, which you can download by clicking the link to the zip file location.
Here are the steps to wrap a function that returns a PL/SQL reference cursor so that it can also return a PL/SQL associative array.
- Create a package specification to hold all the components that are required to manage the process. Assuming that they may have anchored the system reference cursor to something other than a table like a shared cursor, which is a cumbersome implementation design. (I actually chose to exclude this from the book because it’s a stretch as a good coding practice. At least, it is from my perspective. Also, I couldn’t find an example in the Oracle documentation, which led me to believe they didn’t think it’s a great idea either or I could have glossed over it.) You should note that the PL/SQL
RECORD
, Associative Array (collection), and theREF CURSOR
are defined in this package specification.
-- Create a package to hold the PL/SQL record structure. CREATE OR REPLACE PACKAGE example IS -- Force cursors to be read as if empty every time. PRAGMA SERIALLY_REUSABLE; -- Package-level record structure that mimics SQL object type. TYPE common_lookup_record IS RECORD ( common_lookup_id NUMBER , common_lookup_type VARCHAR2(30) , common_lookup_meaning VARCHAR2(255)); -- Package-level collection that mimics SQL object table. TYPE common_lookup_record_table IS TABLE OF common_lookup_record INDEX BY PLS_INTEGER; -- Cursor structure to support a strongly-typed reference cursor. CURSOR c IS SELECT common_lookup_id , common_lookup_type , common_lookup_meaning FROM common_lookup; -- Package-level strongly-typed system reference cursor. TYPE cursor_lookup IS REF CURSOR RETURN c%ROWTYPE; END; / |
- Write a function to return a strongly typed system reference cursor that’s anchored to a cursor defined in the package. This is fairly straightforward when the package specification is done right. You should notice right away that anchoring the original cursor in the package was a horrible practice because you must repeat it all again in the function. In my opinion, you shouldn’t anchor any system reference cursor explicitly to anything other than a table. The cursor could have used the generic weak cursor data type –
SYS_REFCURSOR
. Doing so, saves all the extra lines required by a potential shared cursor.
CREATE OR REPLACE FUNCTION get_common_lookup_cursor ( TABLE_NAME VARCHAR2, column_name VARCHAR2) RETURN example.cursor_lookup IS -- Define a local variable of a strongly-typed reference cursor. lv_cursor EXAMPLE.CURSOR_LOOKUP; BEGIN -- Open the cursor from a static cursor OPEN lv_cursor FOR SELECT common_lookup_id , common_lookup_type , common_lookup_meaning FROM common_lookup WHERE common_lookup_table = TABLE_NAME AND common_lookup_column = column_name; -- Return the cursor handle. RETURN lv_cursor; END; / |
- Write a wrapper function that takes the reference cursor as a formal parameter and returns an Associative Array. You should note that this can’t be called from a SQL context. You must only use it in a PL/SQL context because system reference cursors are PL/SQL only data types.
CREATE OR REPLACE FUNCTION convert_common_lookup_cursor ( pv_cursor EXAMPLE.CURSOR_LOOKUP) RETURN example.common_lookup_record_table IS -- Declare a local counter variable. counter INTEGER := 1; -- Local PL/SQL-only variable. out_record EXAMPLE.COMMON_LOOKUP_RECORD; out_table EXAMPLE.COMMON_LOOKUP_RECORD_TABLE; BEGIN -- Grab the cursor wrapper and return values to a PL/SQL-only record collection. LOOP FETCH pv_cursor INTO out_record; EXIT WHEN pv_cursor%NOTFOUND; -- Assign it one row at a time to an associative array. out_table(counter) := out_record; -- Increment the counter. counter := counter + 1; END LOOP; -- Return the record collection. RETURN out_table; END; / |
- You can test the program in an anonymous block, like the one below. It defines a local Associative Array variable and then assigns the system reference cursor through the wrapper.
-- Open the session to see output from PL/SQL blocks. SET SERVEROUTPUT ON DECLARE -- Define a local associative array. process_table EXAMPLE.COMMON_LOOKUP_RECORD_TABLE; BEGIN -- Print title block. dbms_output.put_line('Converting a SYS_REFCURSOR to TABLE'); dbms_output.put_line('---------------------------------------------------'); -- Run the dynamic variables through the cursor generating function and then convert it. process_table := convert_common_lookup_cursor(get_common_lookup_cursor('ITEM','ITEM_TYPE')); -- Read the content of the Associative array. FOR i IN 1..process_table.COUNT LOOP dbms_output.put('['||process_table(i).common_lookup_id||']'); dbms_output.put('['||process_table(i).common_lookup_type||']'); dbms_output.put_line('['||process_table(i).common_lookup_meaning||']'); END LOOP; END; / |
I hope this answers Gauss’s question. While writing it, I could envision another question that might pop-up. How do you convert an object table type to a PL/SQL context. It was an omission not to include it in that original post on object table types. Here’s how you wrap an object table type into a PL/SQL scope collection.
You might have guessed. It’s done with another wrapper function. At least this is the easiest way to convert the SQL data type to a PL/SQL data type that I see. If you’ve another approach, a better way, let us know.
CREATE OR REPLACE FUNCTION get_common_lookup_record_table ( TABLE_NAME VARCHAR2 , column_name VARCHAR2 ) RETURN example.common_lookup_record_table IS -- Declare a local counter variable. counter INTEGER := 1; -- Define a dynamic cursor that takes two formal parameters. CURSOR c (table_name_in VARCHAR2, table_column_name_in VARCHAR2) IS SELECT * FROM TABLE(get_common_lookup_object_table(UPPER(table_name_in),UPPER(table_column_name_in))); -- A local PL/SQL-only collection variable. list EXAMPLE.COMMON_LOOKUP_RECORD_TABLE; BEGIN -- Grab the cursor wrapper and return values to a PL/SQL-only record collection. FOR i IN c(TABLE_NAME, column_name) LOOP list(counter) := i; counter := counter + 1; END LOOP; -- Return the record collection. RETURN list; END get_common_lookup_record_table; / |
You can then test this in an anonymous block, like so:
-- Open the session to see output from PL/SQL blocks. SET SERVEROUTPUT ON DECLARE -- Declare a local PL/SQL-only collection and assign the value from the function call. list EXAMPLE.COMMON_LOOKUP_RECORD_TABLE; BEGIN -- Print title block. dbms_output.put_line('Converting a SQL Collection to a PL/SQL Collection'); dbms_output.put_line('---------------------------------------------------'); -- Assign wrapped SQL collection to a PL/SQL-only collection. list := get_common_lookup_record_table('ITEM','ITEM_TYPE'); -- Call the record wrapper function. FOR i IN 1..list.COUNT LOOP dbms_output.put('['||list(i).common_lookup_id||']'); dbms_output.put('['||list(i).common_lookup_type||']'); dbms_output.put_line('['||list(i).common_lookup_meaning||']'); END LOOP; END; / |
As always, I hope this helps somebody without paying a fee for content. 😉