Archive for May, 2008
PL/SQL NDS Reference Cursor with Record Collection
Somebody got to this blog looking for a way to write a Native Dynamic SQL (NDS) statement that returned a system reference cursor. I created an image file to show how to do that. I borrowed the code from Chapter 11 of Oracle Database 11g PL/SQL Programming. The only problem with this is that it’s a PL/SQL only solution typically. You can write it as a function or procedure, and then use a Java or PHP program to display the reference cursor in a web page. You can check this previous post for a PHP example.
Leap year, last day of the month the easy way?
You could write an ugly SQL statement full of CASE
statements to derive the leap year moving forward or backward in time. You could likewise write an uglier statement that allows for moving back from a 31 day month to a 30 day month or forward from a 30 day month to a 31 day month.
However, you can use the add_months(date_in,number_of_months)
, like:
Leap year back to a non-leap year (system clock set to 29-FEB-2008):
SQL\> SELECT add_months(SYSDATE,-12) FROM dual; |
From the last day of May to the last day of April (system clock set to 31-MAY-2008):
SQL\> SELECT add_months(SYSDATE,-1) FROM dual; |
From the last day of April to the last day of May (system clock set to 30-APR-2008):
SQL\> SELECT add_months(SYSDATE,1) FROM dual; |
You can read more here in the Oracle SQL Reference.
Leap year not welcome by the TO_YMINTERVAL function
Playing around with illustrating date math, I noticed that Oracle 11g still hasn’t fixed the TO_YMINTERVAL
function. The function should let you to subtract months, years, or a combination of month and years from any date. However, it doesn’t like leap years or going from the last day of a longer month to the last day of a shorter month.
You can add or subtract a year from a date in the middle of the month:
SELECT TO_DATE('15-JAN-08') - TO_YMINTERVAL('01-00') FROM dual; |
You can also add or subtract a month from a date in the middle of the month:
SELECT TO_DATE('15-FEB-08') - TO_YMINTERVAL('00-01') FROM dual; |
You can’t subtract a year from the last day of February in a leap year. There is also no logic to let you add a year to 28-FEB-07 and get 29-FEB-08 (like a Boolean for last_day). Likewise, you can’t add a month to the last day of a month where the next month has fewer days in it; or subtract a month from the last day of a month where the last day is greater than the prior months last day without raising an ORA-01839
error.
Here’s what happens subtracting a year from this years leap day:
SELECT TO_DATE('29-FEB-08') - TO_YMINTERVAL('01-00') FROM dual * ERROR at line 1: ORA-01839: DATE NOT valid FOR MONTH specified |
You can’t complain about it though, it’s apparently compliant with the SQL92 standard according to metalink.
Result cache functions disallow nested table input parameters
If you implement street address as a nested table (or collection), the problem is printing an address book using only a SQL statement. The problem comes from matching up the multiple line return from the TABLE
function with the rest of the row. That’s not a problem when you denormalized the list into known columns.
A PL/SQL function can convert the list into a scalar value. It’s an easy way to leverage a nested table. You can find the full code here. You might think that this is a neat opportunity to use a result cache function. I did, but the behavior isn’t presently supported. On compilation of a function with the RESULT_CACHE
clause and a scalar collection input parameter, you raise a PLS-00999
error.
The message tells you:
RESULT_CACHE IS disallowed ON subprograms WITH IN parameter OF (OR containing) nested TABLE TYPE |
Unnatural outcome of natural joins
You may like the standard syntax of listing tables as comma-delimited lists, rather than using an inner, left, right, full, natural, and cross join syntax. I do! The former method eliminates matching result sets and generally is less tedious.
The natural join is my least favorite of these because it can create problems long after the query is written. The problem is an outcome of its design. A natural join matches rows from one table to another by using all matching column names. This query makes a simplifying assumption: Nobody includes a column of the same name in two tables where they may be joined that isn’t a foreign key.
The following is quick example that creates two tables. The VEHICLE
table uses the VEHICLE_ID
column as a primary key. The WORK_ORDER
table uses the VEHICLE_ID
column as a foreign key.
CREATE TABLE vehicle ( vehicle_id NUMBER , vin VARCHAR2(20)); CREATE TABLE work_order ( work_order_id NUMBER , vehicle_id NUMBER); INSERT INTO vehicle VALUES (1,'VIN_NUMBER1'); INSERT INTO vehicle VALUES (2,'VIN_NUMBER2'); INSERT INTO work_order VALUES (1, 1); INSERT INTO work_order VALUES (2, 2); INSERT INTO work_order VALUES (3, 1); |
The following queries resolve the relationship by using an explicit join:
SELECT * FROM vehicle v, work_order wo WHERE v.vehicle_id = wo.vehicle_id; SELECT * FROM vehicle v JOIN work_order wo ON v.vehicle_id = wo.vehicle_id; SELECT * FROM vehicle v JOIN work_order wo USING(vehicle_id); |
A natural query also resolves the relationship by implicitly finding the columns that share column names, as follows:
SELECT * FROM vehicle v NATURAL JOIN work_order wo; |
All of these return a three row result set. The unnatural part of the natural query arrives during maintenance programming when somebody adds a VIN
column name to the WORK_ORDER
table (let’s say to simplify the ETL to the data warehouse). The code using a natural join isn’t invalidated but its runtime behavior is altered because it now joins both the VEHICLE_ID
and VIN
columns. Continuing the example, you’d change the table by:
ALTER TABLE work_order ADD (vin VARCHAR2(20)); |
The explicit queries still work after the change. The implicit (natural) query now returns no rows because the VIN
column contains all null values, and it is automatically added to the implicit join statement. After updating the VIN
column, the query resolves when the data matches but not when the VIN
column contains different data. What if the VIN
column in WORK_ORDER
only contains the make and model portion of the vehicle identification number while the VIN
column in VEHICLE
contains the complete unique vehicle identifier. You would receive no rows selected from the natural query.
It appears the best thing to do, is avoid natural joins.
I subsequently wrote a post about SQL join semantics. You can find it here.
Reversing direction in a PL/SQL range for-loop
Have you ever wondered how to decrement index values in a PL/SQL range for-loop. You’ve probably heard that you can’t. That’s part true and part false.
The true part is two fold. First, range for-loops move forward from a starting low value to high value. Second, the loop exits immediately when your starting value is high and ending value low. If you use the REVERSE
keyword, the loop moves backward from an ending point to the starting point. This happens because a PL/SQL range for-loop is a guard on entry loop. The starting value is compared against the ending value and exits when the starting value is greater than the ending value.
The false part happens when you want to traverse a collection backward. Oracle collections are varrays, tables, or associative arrays. Associative arrays are also known as PL/SQL tables. You overcome the ascending only limitation by using the REVERSE
keyword or leveraging the Oracle Collection API library functions.
This code works when the index is numeric:
DECLARE TYPE collection IS TABLE OF VARCHAR2(20); fellowship COLLECTION := collection('Frodo','Gandalf','Aragorn'); BEGIN -- Increasing iterator values. FOR i IN REVERSE 1..fellowship.COUNT LOOP DBMS_OUTPUT.put('Iterator ['||i||'] '); DBMS_OUTPUT.put('Value ['||fellowship(i)||']'); DBMS_OUTPUT.new_line(); END LOOP; END; / |
This code works when the index is a string in an associative array:
DECLARE CURRENT VARCHAR2(8); element VARCHAR2(20); TYPE collection IS TABLE OF VARCHAR2(20) INDEX BY VARCHAR2(8); fellowship COLLECTION; BEGIN -- Assign character indexed values. fellowship('Hobbit') := 'Frodo'; fellowship('Wizard') := 'Gandalf'; fellowship('Human') := 'Aragorn'; -- Increasing iterator values. FOR i IN 1..fellowship.COUNT LOOP IF i = 1 THEN -- Set starting point and assign value. CURRENT := fellowship.LAST; element := fellowship(CURRENT); ELSE -- Change value until you read the first element. IF fellowship.PRIOR(CURRENT) IS NOT NULL THEN CURRENT := fellowship.PRIOR(CURRENT); element := fellowship(CURRENT); ELSE -- Exit when all elements read. EXIT; END IF; END IF; DBMS_OUTPUT.put('Iterator ['||i||'] '); DBMS_OUTPUT.put('Index ['||CURRENT||'] '); DBMS_OUTPUT.put('Value ['||element||']'); DBMS_OUTPUT.new_line(); END LOOP; END; / |
Chris Neumüller suggested another example with a WHILE
loop:
DECLARE TYPE collection IS TABLE OF VARCHAR2(20) INDEX BY VARCHAR2(8); fellowship COLLECTION; CURRENT VARCHAR2(20); BEGIN -- Assign character indexed values. fellowship('Hobbit') := 'Frodo'; fellowship('Wizard') := 'Gandalf'; fellowship('Human') := 'Aragorn'; -- Increasing iterator values. IF fellowship.COUNT > 0 THEN CURRENT := fellowship.LAST; WHILE CURRENT IS NOT NULL LOOP DBMS_OUTPUT.put('Iterator ['||CURRENT||'] '); DBMS_OUTPUT.put('Value ['||fellowship(CURRENT)||'] '); DBMS_OUTPUT.new_line(); CURRENT := fellowship.PRIOR(CURRENT); END LOOP; END IF; END; / |
While the former works, you should consider changing the cursor that populates the collection by adding a descending ORDER BY
clause when indexing with a string. The algorithm is a bit more work but it also supports sparsely populated indexes and string-indexed associative arrays. All you need do is swap the LAST
for FIRST
and PRIOR
for NEXT
to go forward through a sparsely populated index.
UTOUG web site updates links
There were two broken links in earlier blogs because UTOUG moved their presentation download repository. I’ve updated those links for my Utah Oracle User Group Training Days 2008 presentations. You can also uses these new links: PL/SQL 11g New Features and an Oracle LOBs. You can learn more about UTOUG and prior presentations at http://www.utoug.org, including Tom Kyte’s Materialized Views presentation from the same 2008 spring conference.
Result cache functions in Oracle 11g return what?
Adrian Billington wrote an excellent article on how to use the Oracle 11g PL/SQL new cross session result cache. He uses Tom Kyte’s runstats tuning kit to show the best performance advantage of this new feature. The recommendation is converting functions that perform SQL lookups to result cache functions. A result cache function’s actual parameters and results are cached only once in the SGA and available across sessions.
A result cache function can only support SQL datatypes. This limits you to returning only a scalar or collection of a scalar datatype from your function. Collections of scalar datatypes are varray or nested table user-defined types (UDT). When you try to return an aggregate table from a result cache function, Oracle 11g Release 1 raises a PLS-00999
error. The error signals an implementation restriction that may be temporary. Let’s hope it changes in Oracle 11g Release 2.
You can cheat the limitation by returning a collection of tokenized strings but I’m not sure it’s worth the effort. If you think it’s worth the effort, you can check out the code.
PHP code to read a PL/SQL reference cursor
The following demonstrates how to read a PL/SQL reference cursor in a PHP program. The reference cursor function is defined in the Pipelined Functions & PL/SQL Tables blog page. I’ve commented it to the hilt for those new to PHP.
The reference cursor maintains a separate connection to the database to access the reference cursor. You also use the oci_fetch_assoc()
function to get the data. That strip_special_characters()
function lets you format your call to the PL/SQL program and remove non-parsing line returns and tabs before running the oci_parse()
function.
<?php // Return successful attempt to connect to the database. if ($c = @oci_connect("plsql","plsql","orcl")) { // Declare input variables. (isset($_GET['table'])) ? $table = (int) $_GET['table'] : $table = 'ITEM'; (isset($_GET['column'])) ? $column = (int) $_GET['column'] : $column = 'ITEM_TYPE'; // Declare a PL/SQL execution command. $stmt = "BEGIN :return_cursor := get_common_cursor(:table,:column); END;"; // Strip special characters to avoid ORA-06550 and PLS-00103 errors. $stmt = strip_special_characters($stmt); // Parse a query through the connection. $s = oci_parse($c,$stmt); // Declare a return cursor for the connection. $rc = oci_new_cursor($c); // Bind PHP variables to the OCI input or in mode variables. oci_bind_by_name($s,':table',$table); oci_bind_by_name($s,':column',$column); // Bind PHP variables to the OCI output or in/out mode variable. oci_bind_by_name($s,':return_cursor',$rc,-1,OCI_B_CURSOR); // Execute the PL/SQL statement & reference cursor. oci_execute($s); oci_execute($rc); // Print the table header with known labels. print '<table border="1" cellpadding="3" cellspacing="0">'; // Set dynamic labels control variable true. $label = true; // Read the contents of the reference cursor. while($row = oci_fetch_assoc($rc)) { // Declare header and data variables. $header = ""; $data = ""; // Read the reference cursor into a table. foreach ($row as $name => $column) { // Capture labels for the first row. if ($label) { $header .= '<td class="e">'.$name.'</td>'; $data .= '<td class="v">'.$column.'</td>'; } else $data .= '<td class=v>'.$column.'</td>'; } // Print the header row once. if ($label) { print '<tr>'.$header.'</tr>'; $label = !$label; } // Print the data rows. print '<tr>'.$data.'</tr>'; } // Print the HTML table close. print '</table>'; // Disconnect from database. oci_close($c); } else { // Assign the OCI error and format double and single quotes. $errorMessage = oci_error(); print htmlentities($errorMessage['message'])."<br />"; } // Strip special characters, like carriage or line returns and tabs. function strip_special_characters($str) { $out = ""; for ($i = 0;$i < strlen($str);$i++) if ((ord($str[$i]) != 9) && (ord($str[$i]) != 10) && (ord($str[$i]) != 13)) $out .= $str[$i]; // Return character only strings. return $out; } ?> |
Pipelined Functions & PL/SQL Tables
Pipelined functions let you retrieve record structures from PL/SQL Tables as rows in SQL statements. PL/SQL tables are also known as associative arrays from 10g forward. While pipelined functions are slower than other approaches, they are easy to implement. The alternative uses a complex query. The query is complex because it typically uses selective aggregation and nested CASE
logic.