MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

Archive for October, 2008

Adapter or not adapter that’s the question

with 3 comments

The Adapter pattern in Object-Oriented OO programming is missing when it comes to how you can read, pass, and manage a PL/SQL system reference cursor. At least, it’s missing for PL/SQL native development. It is available through the OCI but only as a multiple dimensional array of strings.

Here’s an illustration of the Adapter Pattern (courtesy of the Design Patterns book by Gamma, Helm, Johnson, and Vlissides):

There are a few ways to handle reference cursor in PL/SQL. I’ve updated the earlier blog to more completely cover the options. In all cases within a PL/SQL environment, you must know the target type of the PL/SQL record structure. The target for converting a PL/SQL reference cursor is a a PL/SQL record structure.

You can assign a PL/SQL record structure through a PIPELINED table function to an aggregate table, which can be read by SQL. The following query lets you read an aggregate table back into a PL/SQL structure but begs the question of why you’d want to do that. The actual query by itself is in the updated blog entry linked above.

BEGIN
  FOR i IN (SELECT *
            FROM TABLE(use_of_input_cursor(weakly_typed_cursor('Harry')))) LOOP
    DBMS_OUTPUT.put_line('Item Title    ['||i.item_title||']');
    IF i.item_subtitle IS NOT NULL THEN
      DBMS_OUTPUT.put_line('Item Subtitle ['||i.item_subtitle||']');
    END IF;
  END LOOP;
END;
/

The OCI8 driver lets you take the system reference cursor from a PL/SQL block and translate it to a multidimensional array of strings. The following (borrowed from my book on PHP programming with Oracle) demonstrates how to open a statement and a reference cursor, which lets you manage the OUT mode parameter (covered in this earlier post) variable of a PL/SQL reference cursor. Our thanks should go to the OCI team because they see the world of interactivity.

  // Declare a PL/SQL execution command.
  $stmt = "BEGIN
             world_leaders.get_presidents(:term_start
                                         ,:term_end
                                         ,:country
                                         ,:return_cursor);
           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,':term_start',$t_start);
  oci_bind_by_name($s,':term_end',$t_end);
  oci_bind_by_name($s,':country',$country);
 
  // 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.
  oci_execute($s);
 
  // Access the returned cursor.
  oci_execute($rc);

You can query the results of the reference cursor ($rc), like this:

  // 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>';

Moreover, it would be wonderful if Oracle let you implement a full Adapter pattern but there are constructive ways to work with what we’ve got now. You actually get a bit more through the JDBC implementation but that’s for another blog I guess. As to adapter or not adapter, it’s clearly not.

Written by maclochlainn

October 31st, 2008 at 11:00 pm

VMWare Fusion tip on upgrading VMWare Tools

without comments

You’ll need to right click on the VMWareTools icon and manually extract the file. If you don’t and double click the icon instead, it’ll raise an exception that one already exists. After you manually extract it to your desktop, run the command as follows (replacing your user name of course):

# sudo /home/username/Desktop/vmware-tools-distrib/vmware-install.pl

I wrote this when it seemed like a good idea. I subsequently discovered that all upgrades aren’t as good as you’d like. Sometimes, a fresh install recommends itself when the virtual machine is Red Hat AS.

Written by maclochlainn

October 27th, 2008 at 3:39 am

VMWare Fusion 2.x causes Ubuntu printing failure

with 3 comments

I’d already upgraded my Windows x86 instances to 2.x on my Mac Book Pro but hadn’t got around to Ubuntu until today. The upgrade went fine, and VMWare Tools compilation succeeded and kernel reports were normal. Unfortunately, CUPS (Common Unix Printing Service) fails to start correctly and there doesn’t appear to be any way to fix it without changing the VMWare Fusion libraries. It appears to be a bug introduced by VMWare Tools. I’ve updated my Ubuntu VMWare printer set up steps to note it. If you’ve got a fix for the problem, let me know.

Written by maclochlainn

October 27th, 2008 at 2:22 am

Posted in Mac,VMWare

Tagged with , , ,

Quick review of PL/SQL formal parameter modes

without comments

My students wanted a supplement on how variable modes work in PL/SQL, so I figured it would fit nicely in a quick blog entry. If you’re interested, read on …

PL/SQL supports three patterns of variable modes in functions and procedures. The easiest supports a pass-by-value function or procedure, and it is the IN mode of operation. The other two are related but different, and support a pass-by-reference function or procedure. The differences between a function and procedure are straightforward: (1) A function can return a value as an output, which is known as an expression; (2) A function can be used as a right operand; (3) A procedure can’t return a value because it more or less returns a void (borrowing from the lexicon of C, C++, C#, or Java and many other languages), (4) A procedure can be used as a statement by itself in a PL/SQL program while a function can’t. The variables you define in a function or procedure signature (or prototype) are the formal paramters, while the values or variables assigned when calling a function or procedure are the actual parameters.

IN mode:

An IN mode variable is really a copy of the variable, but you can ask to pass a reference. PL/SQL typically obliges when using the IN mode of operation. The following defines a pass-by-value PL/SQL function (other than the return type, you could do the same in a procedure too):

You can test the values of the actual parameter before and after the function call while also testing it inside the function. You can also assign a literal number or string as the actual parameter because the IN mode only requires a value because it discard the variable reference and value when it completes.

There is an exception data type for this IN mode operation, and it is the PL/SQL system reference data type (more on this type can be found in the following post). A PL/SQL reference cursor can only be passed when it is already opened, and it actually passes a reference to the cursor work area in the Private Global Area (PGA).

You can’t assign a value to a formal parameter inside a function when the variable has the default (or IN) mode of operation. Any attempt to do so raises a PLS-00363 with a warning that expression (formal parameter) can’t be used as an assignment target. A test of the function follows:

This seems to be the preferred way to implement functions for beginning programmers.

IN OUT mode:

An IN OUT mode variable is typically a reference to a copy of the actual variable for a couple reasons. If the function or procedure fails the original values are unchanged (this is a departure from the behavior of collections passed as actual parameters in Java). You can assign values to the formal parameter at runtime when using an IN OUT mode variable.

At the conclusion of the function or procedure the internal variable’s reference is passed to the calling program scope and replaces the original reference to the actual parameter. Here’s an example of an IN OUT mode variable in a function.

As you can see the external value is changed inside the function and at completion of the function the external variable passed as an actual parameter is changed:

This seems to be used more frequently in procedures than functions in PL/SQL. However, you can use the approach in either. I’d recommend it for functions that you call through the OCI or Java.

OUT mode:

An OUT mode variable is very much like an IN OUT mode variable with one exception. There is no initial value in it. You must assign a value to an OUT mode variable because it has no value otherwise. If the function or procedure fails, the external variable is unchanged. At the successful conclusion of the function or procedure, the reference for the internal variable replaces the reference to the external scoped variable.

The following shows you the test case:

The OUT mode also has an exception, which relates to CLOB and BLOB datatypes. You can find more about large objects in this presentation made at the Utah Oracle Users Group – Oracle LOBs.

This should be pretty straightforward but if you have suggestions to improve it let me know.

Oracle networking – some ugly ducklings

without comments

I tried to answer a question in the forum a couple weeks ago about connections. It contained all the trite stuff about check this, then that, et cetera because I couldn’t remember why I’d seen an TNS-03505 error. It returns an illustrative message “Failed to resolve name” error. Along the way, I tripped into ORA-12560 and one I’d never seen before an ORA-12518. If you want the dirt on these read on …

TNS-03505
You’ll typically encounter this error when you’re working on a laptop. It gets triggered when you run the tnsping utility. When you’ve qualified the hostname and hostname.domain name in the hosts file and in the tnsnames.ora file, it’ll throw the TNS-03505 error because you’re on another network. You may also encounter it when there’s a change or discrepancy between the machine hostname and DNS server results. Lastly, you may encounter it when you’ve lost the lease on an IP address and now have a new lease with a different IP address.

These errors effectively block successful tnsping calls. You get around it by shutting down the listener, modifying the IP address in the tnsnames.ora file if you’re not using a hostname, setting the %TNS_ADMIN% environment variable in a command session when you have multiple Oracle homes, and restarting the listener.

TNS-12533
This is an doubly annoying error because while it can occur for a meaningful reasons like fat fingering a key word in the ADDRESS descriptor, it can be a stray tab character. That’s why the error text is: TNS:illegal ADDRESS parameters

In vi or vim, you can see hidden characters by typing the : (colon), and enabling list. List shows you hidden characters, like the $ for line returns, et cetera. You run it like this:

:set list

If you see a stray tab character, ^I, remove it and the error should go away. You can disable list by setting nolist.

ORA-01017
This is a principally new error with Oracle 11gR2, and involves the Oracle Call Interface (OCI). You’ll see the errors when you try to change the password of a connect user, and Chris Jones at Oracle explains it well.

ORA-12170
This is generally an easy fix. It typically means that the listener can’t be found. The most frequent cause of the error is a generic installation of the Oracle database or client on a DHCP configured laptop. If there’s no hostname to IP address map defined in the /etc/hosts (Linux or Unix) or the C:\WINDOWS\system32\drivers\etc\hosts file, the installation uses the current IP number. You typically see this error after you’ve fixed your Oracle listener that wouldn’t start by replacing the IP address with a hostname, which is done in the listener.ora file. Unfortunately, you also need to change the same thing in the tnsnames.ora file.

When you connect your laptop to another network, a TNS-12170 exception is thrown. You can fix it by replacing the (HOST = nnn.nnn.nnn.nnn) with the machine name, like (HOST = some_hostname).

ORA-12500
This one generally has two causes. First, when the service was created by somebody other than the Administrator, which can be a user with Administrator role but not in the Administrator group. Second, when the machine doesn’t have enough physical or virtual memory to spawn a new dedicated process.

ORA-12514
This one states that Oracle Listener can’t find the connect descriptor. You get an error like the following:

ORA-12514: TNS:listener does NOT currently know OF service requested IN CONNECT descriptor

The ORA-12514 typically means that the Oracle Listener is running but that Oracle on a Linux or Unix machine, or the Oracle Service on a Windows machine is not started.

ORA-12518
This one is cute. I only hit it because my touchpad is too sensitive on the Dell laptop. It occurs if you pause the Windows listener service. You fix it by restarting the service. It is an enigma within a conundrum (Churchill on the old Soviet Union) why anybody would create a service like this with a pause option. Wouldn’t it be cool if somebody at Oracle were listening now (that is reading this blog) and they got the service fixed.

ORA-12541
This typically means one of two things, which depends on the text of the error. It generally returns either a "no listener" or "could not resolve the connect identifier specified" message text.

The former means the listener isn’t running or can’t be found by the Oracle Instant Client software. If the listener isn’t running, you can start it with the lsnrctl utility, or in Windows by starting the service.

# lsnrctl start

When the listener is running but isn’t seen by an Oracle Instant Client installation or another database through a database link, you probably have a firewall rule in place blocking the port that is listening for incoming traffic. Check your server firewall rules.

The latter error means sqlplus can’t find the tnsnames.ora file. Oracle checks for the tnsnames.ora file in the present working directory, then the location of the $TNS_ADMIN directory (or Windows %TNS_ADMIN%), and finally the location of the $ORACLE_HOME/network/admin directory. If you’re getting this error in a PHP configuration, like a CGI mode, put a copy of the tnsnames.ora file in the same directory as the php-cgi.exe file. Alternatively, you can define the following in your httpd.conf file.

SetEnv TNS_ADMIN "tns_admin_directory"

ORA-12560
This is the sqlplus utility cousin of the TNS-03505. All the rules that apply to it apply to this.

Written by maclochlainn

October 24th, 2008 at 4:18 pm

Posted in Oracle

Tagged with , , ,

AJAX gone wrong, or the dynamic duo Blackboard & IE

with 3 comments

We’ve got an implementation of Blackboard running on Oracle 10g. The new version has a grade book redesign that uses AJAX to eliminate the cumbersome nature of its predecessor. It was interesting figuring out why grades entered wouldn’t show without restarting Internet Explorer, while Firefox and Safari worked fine. Another heart found thank you to Microsoft for failing to optimize JavaScript execution in their browser (all the way through to 8). Read on if you must use IE.

The issue is that Internet Explorer reads JavaScript including all whitespace at initial page load. There’s no attempt to compress it, arghhh. Naturally, that makes performance crawl a bit on initial page load. That wouldn’t be bad but Blackboard’s JavaScript changes DOM values during product use. Those changes go unseen if you navigate from the Grade Book and return to it. At least, they do when you’re using default IE settings. Unlike Microsoft’s solution to the problem of suppressing Mac purchases (an advertising gem from Apple), Microsoft didn’t spend more on marketing (after all the Windows platform is more or less captured by IE). They simply set the default value for page refreshes to automatic, which means once per active IE load into memory for JavaScript files. Then, it is Blackboard’s fault for how it implemented AJAX, right?

You can fix this default by taking one step. Open IE, navigate to Tools, Internet Options, and then click the Settings button in the Browsing history section. The form looks like:

When you click on the Settings button, you’ll come to the following screen. Click the radio button for “Every time I visit the webpage,” which will ensure you get a working grade book in Blackboard.

Click the OK button. You’re not done yet. You must shut down all IE sessions and re-launch the product for the changes to occur. If you think that was tedious, here we need to do it every time our corporate governance folks push an update to Windows because they reset IE to an incompatible set of values for Blackboard’s AJAX implementation.

Written by maclochlainn

October 23rd, 2008 at 9:16 pm

Inline views, fabrication, & the WITH clause

with 4 comments

Sometimes working with a product like Oracle brings a surprise, like a new feature you failed to catch when it was released. I’ve seen a lot of entries using inline views through the WITH clause in the Oracle forums. It caught my eye because it is such a radical departure from portable SQL syntax of an inline view. I finally went searching to find the rationale for this approach.

The answer doesn’t lie with the Charlotte like National Treasure, but with simplifying the join syntax, as qualified in the Oracle Database 2 Day + Data Warehousing Guide 11g, Release 1. The following looks at this approach, and compares using the WITH clause instead of the inline view to perform table fabrication.

Oracle tells us to use the WITH clause when a query has multiple references to the same query block and there are joins and aggregations. The official name of the WITH clause is a subquery factoring clause. Basically, the WITH clause lets you name inline views and then reuse them inside other inline views. This behavior avoids having to call different copies of the same inline view in different parts of a query or DML statement, which reduces overhead and increases view response time for resolution.

Like local named PL/SQL blocks, subquery factoring clauses must be defined before they can be referenced. Unlike PL/SQL, they have no equivalent function and procedure stubs used for forward referencing in a PL/SQL program unit. They simply become available in sequence, the top most universally available and the next only available below to those statements below it.

The WITH clause (or subquery factoring clause) feature comes to us from the ANSI SQL:1999 specification. It is implemented in Oracle databases with the same syntax as it is in Microsoft SQL Server 2005. The only difference is Microsoft brands it as a Common Table Expression (CTE). It also happens to be the only way to implement a recursive query in Microsoft SQL Server.

The basic syntax is:

The first code block is assigned the subquery factoring clause’s name. You can then reuse the name in subsequent code blocks or the master query. The idea is that this syntax is simpler than the traditional inline view approach and more efficient.

The WITH clause is also capable of letting you create tables from literal values, which is known as table fabrication. The following syntax uses the with clause to fabricate a table of two columns (x and y) and two rows.

SQL> WITH fabricated AS
  2   (SELECT 1 AS x, 2 AS y FROM dual
  3    UNION ALL
  4    SELECT 3 AS x, 4 AS y FROM dual)
  5    SELECT x, y FROM fabricated;

This produces the following results:

         X          Y
---------- ----------
         1          2
         3          4

The next shows the traditional way of fabricating a table using an inline view:

SQL> SELECT x, y
  2   FROM (SELECT 1 AS x, 2 AS y FROM dual
  3         UNION ALL
  4         SELECT 3 AS x, 4 AS y FROM dual) fabricated;

This also produces the same results as before, two rows of X and Y variables.

You can also use this type of syntax in MySQL to fabricate a table. You can’t use the WITH clause in MySQL because it’s not supported. You’ll notice in the example that the FROM dual portion is omitted in MySQL. Wouldn’t it be nice if Oracle let that happen too?

SQL> SELECT x, y
  2  FROM  (SELECT 1 AS x, 2 AS y
  3         UNION ALL
  4         SELECT 3 AS x, 4 AS y) fabricated;

A neat function that I picked up on the Oracle Technical Network is the NUMTODSINTERVAL (number to date-stamp interval) function, which can create intervals for qualifying sales by hour or quarter hour. More or less it is a way to fabricate timing intervals. Here’s a quick example:

SQL> SELECT   TO_CHAR(SYSDATE - NUMTODSINTERVAL(dist,'HOUR')
  2                  ,'DD-MON-YYYY HH24:MI:SS') bracket
  3  FROM    (SELECT 1 AS dist FROM dual
  4           UNION ALL
  5           SELECT 2 AS dist FROM dual
  6           UNION ALL
  7           SELECT 3 AS dist FROM dual) fabricated;

The output is:

BRACKET
-------------------
22-OCT-2008 23:07:15
22-OCT-2008 22:07:15
22-OCT-2008 21:07:15

This has been the syntax, now I’ll have to check whether there are any performance differences. I suspect that since the execution plan is the same that there aren’t any performance differences but you never know until you test it.

More or less they were but I tripped into a performance shortfall of the WITH clause. It was a complete accident when I was trying to convert a MySQL SQL syntax model into Oracle SQL. The smaller change to the code was to use a WITH clause but I found it didn’t work.

You can’t use the WITH clause inside a subquery for a multiple row insert. It raises an ORA-32034 error if you attempt it, which struck me as bizare. A normal inline view works fine but the WITH clause doesn’t.

Here’s a simple example of embedding an inline view into an INSERT statement. It works seamlessly in Oracle 11g:

INSERT INTO contact_copy
( SELECT   contact_s1.nextval
  ,        1001
  ,        cl.contact_type
  ,        'Doe'
  ,        'John'
  ,        NULL
  ,        3
  ,        SYSDATE
  ,        3
  ,        SYSDATE
  FROM     dual
  CROSS JOIN
 (SELECT   common_lookup_id AS contact_type
  FROM     common_lookup
  WHERE    common_lookup_type LIKE '%DAY RENTAL') cl );

When I switched to what appeared as the equivalent syntax using a WITH clause, it failed and raised the ORA-32034: unsupported use of with clause error. The following shows you how the WITH would be used, if it could be used:

INSERT INTO contact_copy
( WITH  cl AS
 (SELECT   common_lookup_id AS contact_type
  FROM     common_lookup
  WHERE    common_lookup_type LIKE '%DAY RENTAL')
  SELECT   contact_s1.nextval
  ,        1001
  ,        cl.contact_type
  ,        'Doe'
  ,        'John'
  ,        NULL
  ,        3
  ,        SYSDATE
  ,        3
  ,        SYSDATE
  FROM     dual );

I thought that might be the reason why Oracle didn’t bother putting it in the SQL reference manual for Oracle Database 10g or 11g. However, Dominic Brooks provided the correct syntax. Very interesting that you simply start with the WITH clause and exclude the enclosing parentheses. Quite a departure from the normal syntax for a multiple row insert.

The correct syntax when the subquery cl returns only one row is like Dominic’s suggestion:

INSERT INTO contact_copy
WITH  cl AS
(SELECT   common_lookup_id AS contact_type
 FROM     common_lookup
 WHERE    common_lookup_type LIKE '%DAY RENTAL')
 SELECT   contact_s1.nextval
 ,        1001
 ,       (SELECT cl.contact_type FROM cl)
 ,        'Doe'
 ,        'John'
 ,        NULL
 ,        3
 ,        SYSDATE
 ,        3
 ,        SYSDATE
 FROM     dual;

The correct syntax when the subquery cl subquery returns more than one row differs from Dominic’s. You need a CROSS JOIN to multiply the other static values by the number of rows returned by the subquery so that you have a multiple row insert statement.

INSERT INTO contact_copy
WITH  cl AS
(SELECT   common_lookup_id AS contact_type
 FROM     common_lookup
 WHERE    common_lookup_type LIKE '%DAY RENTAL')
 SELECT   contact_s1.nextval
 ,        1001
 ,        cl.contact_type
 ,        'Doe'
 ,        'John'
 ,        NULL
 ,        3
 ,        SYSDATE
 ,        3
 ,        SYSDATE
 FROM     dual CROSS JOIN cl;

It turned into a longer discussion than I anticipated. Hope it helps solve problems and tune Oracle queries.

Reflecting on six months of blogg’n

without comments

It is nice to know that the entries I’ve made have readers. It’s surprising to see almost 22,000 direct hits and another 5,000 syndicated hits in the 6 months of blogg’n. The following table contains the list and links of the top blogs that have netted 5 or more hits per day.

Blog Entry Posted Hits Avg
How to configure Mac OS X as an Oracle Client 9/2/2008 1,402 36
How to convert XML to CSV and upload into Oracle 6/22/2008 1,019 9
Creating an external table that uses SQL*Loader 6/19/2008 945 8
Creating an external table that uses Oracle Data Pump 6/19/2008 899 8
Pipelined functions and PL/SQL Tables 5/11/2008 859 5
Reading an external directory from SQL or PL/SQL 6/05/2008 667 5

I plan to move this to my own site shortly and will provide notice and pay WordPress to forward. Naturally, any comments are welcome.

Written by maclochlainn

October 17th, 2008 at 11:05 pm

Posted in Oracle

Setting up a printer in VMWare Ubuntu instance

without comments

As I mentioned before, working in the virtual machine is a great solution when you need to work in multiple operating systems. Setting up printing is a step that goes with the operating system. It is very easy to configure in Ubuntu running in VMWare on a Mac OS X machine.

I found that the standard printer in the virtual machine wouldn’t work. I tried it in both VMWare 1.x and 2.x but without any luck. It did work ineffectively in VMWare 2.x but it embedded characters in simple documents that shouldn’t be there. Finally, I pursued this course. It has the benefit of working like you’d expect! It lets you print your native Ubuntu documents when you’ve configured the VMWare machine in NAT or bridged networking mode. The only difference is that a bridged network doesn’t require you to share the printer on the Mac OS because it directly accesses it.

The first step using a NAT network requires that you share you printer setup on the Mac OS. You do that by launching System Preferences, then click on Sharing. In Sharing, you enable print sharing by chosing the network printer …

After you’ve enabled sharing on the Mac OS, you can take the following steps in Ubuntu:

1. Click the System menu choice, choose Administration. and Printing, as shown in screen shot:

2. You’ll then see the following screen but not gray scaled. If you don’t, you’ll also see the following form. a gray scaled version indicates that you’ve run VMWare Tools before updating the Ubuntu OS CUPS service:

As mentioned, this means there’s a problem with a disabled service – typically cups (Common Unix Printing Service). You can click the Help, then Troubleshoot to further diagnose the problem. In the first screen click the Forward button to continue. In this screen, click the Not Listed (because it should be an empty list), and then click the Forward button to continue. You most likely will see the following dialog box, which tells you that the cups service is stopped (a general occurrence when you upgrade from VMWare Fusion 1.x to 2.x).

There’s a temptation to follow the instructions, and I yielded to it without a positive outcome. What you’ll find is that the cups (cupsys) service is enabled but if you use the VMWare Fusion menu, you’ll find that it isn’t, as shown:

If you stop here and check in a terminal session, you’ll see that life isn’t rosy after the upgrade. Even if you check it and restart the VM, the printing problem won’t resolve. This appears to be a part of the recompilation of cups by the VMWare Tools. It appears to happen when you opt to compile Ubuntu CUPS while running the VMWare Tools. You’re only prompted to compile these if you’re not on the most current CUPS release by Ubuntu.

You use the following command to check the status of the printer service:

# sudo /etc/init.d/cupsys status

You will most likely get something like this if you have a problem:

Status of Common Unix Printing System: cupsd is not running but /var/run/cups/cupsd.pid exists.

This is where it becomes obvious that the VMWare Fusion 2.x upgrade can introduce the problem. It is simple to avoid the problem by ensuring that the Ubuntu OS is patched to the most current CUPs version before running the VMWare Tools. I fixed the problem by reinstalling Ubuntu from scratch, and patching it to the current level. Then, you won’t have a failure of the CUPS process.

When you fix any errors from the upgrade or provided you’re on VMWare Fusion 2.x, you should click the Show printers shared by other systems check box, then click the Refresh button to display any network printers if they don’t refresh automatically.

3. You click on the desired network printer, which displays the following screen. Click the Make Default button after you click the Print Test Page button.

If you caught my post on doing this in a Microsoft Windows environment, isn’t it stuning how easy Ubuntu is compared to the “user-friendly” Windows interface (unless you’re upgrading). If you need the Windows instructions, you can find them here.

Reference Cursors – Why, when, and how?

with 8 comments

A week or two ago, I noticed a discussion on the Oracle Technical Network forum that asked some questions about reference cursors. The discussion made me reflect if there were a couple simple rules for using reference cursors. This contains my take on the rules and some examples.

What are they …
There are two types of reference cursors. They are either weakly or strongly typed PL/SQL only data types. A weakly typed cursor doesn’t anchor the output of a query to a table or view, and implements the PL/SQL SYS_REFCURSOR type. A strongly typed cursor anchors the output of a query to a table or view, and typically anchors itself to a package or local user defined type (UDT) of a cursor.

They’re defined in the declaration block or a package specification, like this:

TYPE weak_cursor IS REF CURSOR;
TYPE strong_cursor IS REF CURSOR RETURN table_name%ROWTYPE;

When you opt to use a weakly typed cursor, you can anchor it to a PL/SQL structure that is a collection of a PL/SQL record structure. This is known as an associative array, and commonly called a PL/SQL table by folks who pre-date the Oraclei documentation that Oracle would prefer we forget. However, it seems politically insensitive to use that language even though Oracle published it as such in the Oracle 8 documentation because it isn’t really a table but an implementation of a list of record structures. That means the index is sparsely populated or may contain breaks in a numeric index sequence. You can also use character string indexes from Oracle 10g forward to index this type of collection.

Why should you use them …
They’re useful structures when you want to open a cursor with known output columns in one program unit and move it to another for processing. Strongly typed reference cursors are appropriate for this purpose when both the passing and calling program units are in PL/SQL. Weakly typed reference cursors can also be used passing and calling PL/SQL programs. Weakly typed reference cursors require the same structures as strong reference cursors. Specifically, you will need a record structure for row-by-row fetch and collection of a record structure for bulk fetch. Whether you define them as strong or weak, you’ll need these structures for use inside PL/SQL program units that read the cursor. As a rule of thumb, you should generally define them as strongly typed reference cursors when they’re used exclusively in PL/SQL.

The most effective use of weakly typed reference cursors is in external OCI programming languages. Actually, it appears that weakly typed cursors have little use anywhere but in an OCI program. In external programming languages, you can fetch associations and dynamically discover the structure of a weakly typed reference cursor. That’s why they’re useful in OCI programming languages. You can find an example of using a weakly typed cursor in a PHP program on this blog entry.

How you use them …
You can find an example of using a weakly typed reference cursor as an input parameter in this discussion of pipelined PL/SQL functions. You can return a weakly typed cursor from an NDS (Native Dynamic SQL) statement as follows:

-- Creates a function to dynamically open a cursor and return it as a return type.
CREATE OR REPLACE FUNCTION weakly_typed_cursor
(title_segment VARCHAR2) RETURN SYS_REFCURSOR IS
  weak_cursor SYS_REFCURSOR;
  stmt VARCHAR2(4000);
BEGIN
  -- Create dynamic SQL statement.
  stmt := 'SELECT item_title, item_subtitle '
       || 'FROM   item '
       || 'WHERE  REGEXP_LIKE(item_title,:input)';
  -- Explicit cursor structures are required for system reference cursors.
  OPEN weak_cursor FOR stmt USING title_segment;
  RETURN weak_cursor;
 
END;
/

Outside of an OCI program, the only explicit way to query this is with a SQL statement like:

SQL> VARIABLE cursor REFCURSOR
SQL> CALL weakly_typed_cursor('Harry') INTO :cursor
SQL> SELECT :cursor FROM dual;

Alternatively, you can do the following implicit call:

SQL> SELECT weakly_typed_cursor('Harry') FROM dual;

If you tried to select it using the TABLE function, you’d get the following error:

SQL> SELECT * FROM TABLE(weakly_typed_cursor);
     *
ERROR at line 2:
ORA-22905: cannot access ROWS FROM a non-nested TABLE item

You can return and query a weakly typed cursor as a strongly typed cursor by doing four things. Anchor the cursor statement to a table or view in the database catalog. Create a record structure to store rows of the reference cursor in an ordinary fetch, or a record structure and associative array collection data type to store a set of rows of the reference cursor. Then, explicitly open the reference cursor into the variable. Here is the detail to support those steps:

1. Create a package specification, that acts like an Object-oriented interface because all it contains are type definitions that you’ll implement in other code modules (provided they have the EXECUTE privilege on the package):

-- Create a structure declaration package, like an interface or abstract class.
CREATE OR REPLACE PACKAGE pipeliner IS
  -- Declares a row structure that doesn't map to a catalog object.
  TYPE title_structure IS RECORD
  (item_title    VARCHAR2(60)
  ,item_subtitle VARCHAR2(60));
  -- Declares an associative array, or a collection of a PL/SQL row structure.
  TYPE title_collection IS TABLE OF title_structure;
END pipeliner;
/

2. You use the WEAKLY_TYPED_CURSOR function presented earlier in this blog to create a weakly typed cursor as the return type of a stored function.

3. The last step creates a function that translates a weakly typed reference cursor into an aggregate table by using a pipelined function, as shown in the illustration.

-- A function that receives a cursor as an input and returns an aggregate table.
CREATE OR REPLACE FUNCTION use_of_input_cursor
(incoming_cursor SYS_REFCURSOR)
RETURN pipeliner.title_collection PIPELINED IS
  counter           NUMBER := 1;
  active_record     PIPELINER.TITLE_STRUCTURE;
  active_collection PIPELINER.TITLE_COLLECTION:=
                      pipeliner.title_collection();
BEGIN
  -- A simple loop allows you to fetch the already open cursor
  LOOP
    FETCH incoming_cursor INTO active_record;
    EXIT WHEN incoming_cursor%NOTFOUND;
    -- Extend collection, assign a value.
    active_collection.EXTEND;
    active_collection(counter) := active_record;
	-- Add a row to the aggregate return table.
    PIPE ROW(active_collection(counter));
    counter := counter + 1;
  END LOOP;
  CLOSE incoming_cursor;
  RETURN;
END;
/

The PIPE command transfers a scalar variable or record structure into a row of a target aggregate table, which can be read through the TABLE command in a SQL statement. A neat thing that happens in the example, is that it simply transfers the whole row returned by the cursor as an instance ACTIVE_RECORD into an indexed element of the ACTIVE_COLLECTION collection. The alternative would be syntax like the following:

active_collection(counter).item_title := active_record.item_title;
active_collection(counter).item_title := active_record.item_subtitle;

While those are neat features that may be copied from example code, they’re useless. The more direct way to create this translation program eliminates the collection entirely.

-- A function that receives a cursor as an input and returns an aggregate table.
CREATE OR REPLACE FUNCTION use_of_input_cursor
(incoming_cursor SYS_REFCURSOR)
RETURN pipeliner.title_collection PIPELINED IS
  counter           NUMBER := 1;
  active_record     PIPELINER.TITLE_STRUCTURE;
BEGIN
  -- A simple loop allows you to fetch the already open cursor
  LOOP
    FETCH incoming_cursor INTO active_record;
    EXIT WHEN incoming_cursor%NOTFOUND;
	-- Add a row to the aggregate return table.
    PIPE ROW(active_record);
  END LOOP;
  CLOSE incoming_cursor;
  RETURN;
END;
/

Another alternative would be to do a BULK COLLECT directly into the collection. The next example demonstrates that but you should note that you can’t use a FORALL when assigning collection values to a PIPE for a pipelined function.

-- A function that receives a cursor as an input and returns an aggregate table.
CREATE OR REPLACE FUNCTION use_of_bulk_cursor
(incoming_cursor SYS_REFCURSOR)
RETURN pipeliner.title_collection PIPELINED IS
  active_collection PIPELINER.TITLE_COLLECTION:=
                      pipeliner.title_collection();
BEGIN
  -- A bulk collect fetch the already open cursor
  FETCH incoming_cursor BULK COLLECT INTO active_collection;
  FOR i IN 1..active_collection.COUNT LOOP  
	-- Add a row to the aggregate return table.
    PIPE ROW(active_collection(i));
  END LOOP;
  CLOSE incoming_cursor;
  RETURN;
END;
/

4. In SQL, you can query the result from either the use_of_input_cursor using the following syntax:

-- Query the results.
SELECT *
FROM TABLE(use_of_input_cursor(weakly_typed_cursor('Harry')))
/

… or use_of_bulk_cursor using the following syntax:

-- Query the results.
SELECT *
FROM TABLE(use_of_bulk_cursor(weakly_typed_cursor('Harry')))
/

You can change the prior query to call the use_of_bulk_cursor function to test the bulk collect operation. It didn’t seem worth the effort of doing another screen shot.

More or less, the limitation exists because when operating exclusively inside of PL/SQL there is no way currently to support an Adapter OO pattern. You can implement an Adapter pattern if you use an OCI8 external programming language to read the cursor as a dynamic result set (really only a multi-dimensional array of strings – or technically because the index is sparse a list).

Alternatively in a PL/SQL only solution, you can simply use a strongly typed cursor and bundle all the components into a single program unit. Assuming you create a two column view from the ITEM table, you can use the following query (code base can be downloaded from McGraw-Hill for the Oracle Database 11g PL/SQL Programming book):

DECLARE
  TYPE cursor_record IS RECORD
  ( item_title    item.item_title%TYPE
  , item_subtitle item.item_subtitle%TYPE );
  t CURSOR_RECORD;
  TYPE strong_type IS REF CURSOR RETURN item_title%ROWTYPE;
  c STRONG_TYPE;
BEGIN
  OPEN c FOR SELECT item_title, item_subtitle FROM item;
  LOOP
    FETCH c INTO t;
      EXIT WHEN c%NOTFOUND;
      DBMS_OUTPUT.put_line(t.item_title);
  END LOOP;
  CLOSE c;
END;
/

If you like this, you should check out another wrapping technique here. If you’d like another system reference example, post a comment to let me know.

Written by maclochlainn

October 11th, 2008 at 6:03 am