Archive for the ‘ORA-22992’ tag
Cows don’t fly and LOBs don’t resolve across a DB_LINK
Last week, I was wrapping up an on-site engagement. I couldn’t help but notice that while cows don’t fly, some may appear to fly, as shown in this photo. I took it with my iPhone, in front of the Salt Palace in Salt Lake City, Utah.
I’d been asked a question about whether you can build a view based on a DB_LINK
to a LOB. My answer was no but you can write a Java socket and stored procedure to mimic it. Fortunately, they found an external API to solve their immediate problem.
Poking around on the web, there were a few apparently twisted approaches to creating a DB_LINK
. There wasn’t a single place where they all had answer, so here’s a stab at it.
Failing to include a USING
clause:
It seems that some new folks in the Oracle Community can be challenged by the USING clause in the CREATE DATABASE LINK
command syntax. There were a few examples raising ORA-02019
errors. This is the likely syntax that causes it:
CREATE DATABASE LINK demo_db_link CONNECT TO plsql IDENTIFIED BY plsql; |
I was surprised that you could create a database link without an error with this syntax. Shouldn’t it raise an error and prevent giving the impression that it works?
It does raise an error when you try to resolve the database link, as …
SELECT item_title FROM item@demo_db_link WHERE item_id = 1021; |
This raises the following exception:
FROM item@demo_db_link * ERROR at line 2: ORA-02019: connection description FOR remote DATABASE NOT found |
The error message is clear if you understand that you can’t create a database link without the USING
clause. It appears the reason newbies go down this route is this error:
CREATE DATABASE LINK demo_db_link CONNECT TO plsql IDENTIFIED BY plsql USING mclaughlin11g; |
This raises the following exception:
USING mclaughlin11g * ERROR at line 3: ORA-02010: missing host CONNECT string |
This error generates because the hostname
isn’t a known identifier in SQL. The same error would occur if you substituted a valid TNS Alias name. As the documentation states, the value provided to the USING
clause is a string and must be delimited by single quotes.
Reactive Programming:
Oracle’s errors aren’t bad, but then some are misleading without some experience. If a newbie got the prior error, they’d probably figure out that they need to enclose the “host connect string
” in single quotes. They might create a database link like this with the machine hostname
:
CREATE DATABASE LINK demo_db_link CONNECT TO plsql IDENTIFIED BY plsql USING 'mclaughlin11g'; |
It appears to work because there’s no validation of the link at creation time. Maybe there should be some validation, and it should raise an error when it isn’t found. This would be immediate feedback, and probably save beginners some time. Instead, they’ll get this error when they run it:
SELECT item_title FROM item@demo_db_link WHERE item_id = 1021; |
This raises the following exception:
FROM item@demo_db_link * ERROR at line 2: ORA-12504: TNS:listener was NOT given the SERVICE_NAME IN CONNECT_DATA |
Now, this is a definitive error message!!! It tells an experienced Oracle developer to look in the tnsnames.ora file. Hopefully, it leads a newbie to the same file. You probably agree it’s a clear error message.
Putting the pieces together:
Opening the $ORACLE_HOME/network/admin/tnsnames.ora
or %ORACLE_HOME%\network\admin\tnsnames.ora
file gives us the following orcl
service name:
ORCL = (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = mclaughlin11g)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = orcl) ) ) |
The USING clause should point to a SERVICE_NAME
value (oops, I forgot to overlay the color on that). You then create the database link with the following syntax:
CREATE DATABASE LINK demo_db_link CONNECT TO plsql IDENTIFIED BY plsql USING 'orcl'; |
Now the database link resolves as …
SELECT item_title FROM item@demo_db_link WHERE item_id = 1021; |
and it returns …
ITEM_TITLE ---------------------------------------- Harry Potter and the Sorcerer's Stone |
Large Objects (LOBs) don’t work across database links:
While the database link works, if we attempt to access a CLOB
or BLOB
column it fails. This is demonstrated by the next screen shot:
SELECT item_title FROM item@demo_db_link WHERE item_id = 1021; |
This raises the following exception:
ERROR: ORA-22992: cannot USE LOB locators selected FROM remote TABLES |
Why does it fail? That’s a great question. LOBs are references in the database. They require a thread into the SGA for reading and writing. The thread can only exist in the scope of a transaction. You can’t create a transaction context across a database link. Therefore, a database link does not support a remote thread. You can fix this by writing a socket routine to place a temporary LOB in the local database. I’ll try to get back to this in a week or two and provide an example.