Oracle® Transparent Gateway for Informix Administrator's Guide 10g Release 2 (10.2) for Solaris Operating System (SPARC) Part Number B14275-01 |
|
|
View PDF |
After the gateway is installed and configured, you can use the gateway to access Informix data, pass Informix commands from applications to the Informix database, perform distributed queries, and copy data.
This chapter contains the following sections:
The gateway can pass Informix commands or statements from the application to the Informix database using the DBMS_HS_PASSTHROUGH package.
Use the DBMS_HS_PASSTHROUGH package in a PL/SQL block to specify the statement to be passed to the Informix database, as follows:
DECLARE
num_rows INTEGER;
BEGIN
num_rows := DBMS_HS_PASSTHROUGH.EXECUTE_IMMEDIATE@IFMX('command');
END;
/
Where command cannot be one of the following:
COMMIT
CREATE DATABASE
DROP DATABASE
ROLLBACK
ROLLFORWARD DATABASE
Informix tool commands
The DBMS_HS_PASSTHROUGH package supports passing bind values and executing SELECT statements.
See Also: PL/SQL Packages and Types Reference and Chpater 3 of Oracle Heterogeneous Connectivity Administrator's Guide for more information about the DBMS_HS_PASSTHROUGH package. |
Informix and Oracle databases function differently in some areas, causing compatibility problems. The following compatibility issues are described in this section:
The American National Standards Institute (ANSI) has established a set of industry standards for SQL. The gateway supports only Informix databases that comply with the ANSI standard. For more information about how to create or start up an ANSI-compliant Informix database, refer to your Informix documentation.
Naming rule issues include the following:
Oracle and Informix use different database object naming rules. For example, the maximum number of characters allowed for each object name can be different. Also, the use of single and double quotation marks, case sensitivity, and the use of alphanumeric characters can all be different.
See Also: Oracle Database Reference and Informix documentation. |
Names of Informix database objects are limited to a maximum of 18 characters. An object name can be composed of these characters:
Numbers 0 to 9
Lowercase letters a to z
Uppercase letters A to Z
Underscore character (_)
Informix handles letter case differently from Oracle. Informix uses these rules:
Table owner names default to uppercase letters, unless the name is surrounded by double quote characters
Column names, table names, view names, and so on, are always treated as lowercase letters
The Oracle database server defaults to uppercase unless you surround identifiers with double quote characters. For example, to refer to the Informix table called emp, enter the name with double quote characters, as follows:
SQL> SELECT * FROM "emp"@IFMX;
However, to refer to the Informix table called emp owned by Scott from an Oracle application, enter the following:
SQL> SELECT * FROM "Scott"."emp"@IFMX;
If the Informix table called emp is owned by SCOTT, a table owner name in uppercase letters, you can enter the owner name without double quote characters, as follows:
SQL> SELECT * FROM SCOTT."emp"@IFMX;
Or
SQL> SELECT * FROM scott."emp"@IFMX;
Oracle Corporation recommends that you surround all Informix object names with double quote characters and use the exact letter case for the object names as they appear in the Informix data dictionary. This convention is not required when referring to the supported Oracle data dictionary tables or views listed in Appendix C, "Data Dictionary".
If existing applications cannot be changed according to these conventions, create views in Oracle to associate Informix names to the correct letter case. For example, to refer to the Informix table emp from an existing Oracle application by using only uppercase names, define the following view:
SQL> CREATE VIEW EMP (EMPNO, ENAME, SAL, HIREDATE) AS SELECT "empno", "ename", "sal", "hiredate" FROM "emp"@IFMX;
With this view, the application can issue statements such as the following:
SQL> SELECT EMPNO, ENAME FROM EMP;
Using views is a workaround solution that duplicates data dictionary information originating in the Informix data dictionary. You must be prepared to update the Oracle view definitions whenever the data definitions for the corresponding tables are changed in the Informix database.
Note: The DELIMIDENT Informix parameter must be set in the Informix client in order for Informix to accept double quotation marks around object names. |
Data type issues include the following:
Oracle SQL uses hexadecimal digits surrounded by single quotes to express literal values being compared or inserted into columns defined as data type RAW.
This notation is not converted to syntax compatible with Informix BINARY, BYTE and TEXT data types (a 0x followed by hexadecimal digits, surrounded by single quotes).
For example, the following statement is not supported:
SQL> INSERT INTO BYTE_TAB@IFMX VALUES ('Oxff');
Where BYTE_TAB contains a column of data type BINARY, BYTE or TEXT. Use bind variables when inserting into or updating BINARY, BYTE or TEXT data types.
Informix does not support implicit date conversions. Such conversions must be explicit.
For example, the gateway issues an error for the following SELECT statement:
SELECT DATE_COL FROM TEST@IFMX WHERE DATE_COL = "1-JAN-2001";
To avoid problems with implicit conversions, add explicit conversions, as in the following:
SELECT DATE_COL FROM TEST@IFMX WHERE DATE_COL = TO_DATE("1-JAN-2001")
Query issues include the following:
Informix evaluates a query condition for all selected rows before returning any of the rows. If there is an error in the evaluation process for one or more rows, no rows are returned even though the remaining rows satisfy the condition.
Oracle evaluates the query condition row-by-row and returns a row when the evaluation is successful. Rows are returned until a row fails the evaluation.
The gateway processes an empty string in a SQL statement as a null value. Informix Server processes an empty string as an empty string.
Comparing to an empty string
The Gateway passes literal empty strings to the Informix Server database without any conversion. If you intended an empty string to represent a null value, Informix does not process the statement that way; it uses the empty string.
You can avoid this problem by using NULL or IS NULL in the SQL statement instead of the empty string syntax, as in the following example:
SELECT * from "emp"@IFMX where "ename" IS NULL;
Selecting an empty string
For VARCHAR columns, the gateway returns an empty string to the Oracle database server as NULL value.
For CHAR columns, the gateway returns the full size of the column with each character as empty space (' ').
The locking model for an Informix database differs significantly from the Oracle model. The gateway depends on the underlying Informix behavior, so Oracle applications that access Informix through the gateway can be affected by the following possible scenarios:
Read access might block write access
Write access might block read access
Statement-level read consistency is not guaranteed
See Also: Informix documentation for information about the Informix locking model. |
If you encounter incompatibility problems not listed in this section or in "Known Problems", please contact Oracle Support Services. The following section describes the known restrictions and includes suggestions for dealing with them when possible:
COMMIT or ROLLBACK in PL/SQL Cursor Loops Closes Open Cursors
Note: If you have any questions or concerns about the restrictions, contact Oracle Support Services. |
The gateway cannot guarantee transactional integrity in the following cases:
When a statement that is processed by the gateway causes an implicit commit in the target database
When the target database is configured to work in autocommit mode
Note: Oracle corporation strongly recommends the following:
|
The gateway does not support savepoints. If a distributed update transaction is under way involving the gateway and a user attempts to create a savepoint, the following error occurs:
ORA-02070: database dblink does not support savepoint in this context
By default, the gateway is configured as COMMIT_CONFIRM and in this transaction mode it is always the commit point site when the Informix database is updated by the transaction.
Any COMMIT or ROLLBACK issued in a PL/SQL cursor loop closes all open cursors, which can result in the following error:
ORA-1002: fetch out of sequence
To prevent this error, move the COMMIT or ROLLBACK statement outside the cursor loop.
If the SQL statements being passed through the gateway result in an implicit commit at the Informix database, the Oracle transaction manager is unaware of the commit and an Oracle ROLLBACK command cannot be used to roll back the transaction.
Informix SMALLFLOAT and REAL data types have a precision of 6.
The gateway cannot select a column defined with an Informix NCHAR or NVARCHAR data type.
This section lists restrictions on the following SQL syntax:
See Also: Appendix B, "Supported SQL Syntax and Functions" for more information about restrictions on SQL syntax. |
UPDATE and DELETE statements with the WHERE CURRENT OF clause are not supported by the gateway because they rely on the Oracle ROWID implementation. To update or delete a specific row through the gateway, a condition style WHERE clause must be used.
The NULL keyword cannot be used in the select list of a SELECT statement because that syntax is not ANSI SQL.
For example, the following statement cannot be used:
SQL> SELECT NULL FROM ...
Subqueries of INSERT statements cannot use multiple aliases for the same table. For example, the following statement is not supported:
SQL> INSERT INTO "emp_target"@IFMX SELECT a."empno" FROM "emp_source"@IFMX a, "emp_source"@IFMX b WHERE b."empno"=9999
SQL statements in subqueries of DELETE, INSERT, and UPDATE statements cannot refer to the same table as specified in the outer query. This is because of the locking mechanism in Informix.
In SQL*Plus, the gateway does not support using a SELECT statement to retrieve data from an Informix column defined as data type BYTE.
You need to use double quotes to wrap around lowercase table names, for example:
copy from tkhouser/tkhouser@inst1 insert loc_tkhodept using select* from "tkhodept"@holink2;
The gateway is not multithreaded and cannot support shared database links. Each gateway session spawns a separate gateway process and connections cannot be shared.
Only the first 64 characters of the view definition are returned when querying ALL_VIEWS and USER_VIEWS in the gateway data dictionary.
This section describes known problems and includes suggestions for correcting them when possible. If you have any questions or concerns about the problems, contact Oracle Support Services. A current list of problems is available online. Contact your local Oracle Corporation office for information about accessing the list.
The following known problems are described in this section:
Oracle database server no longer supports the initialization parameter DBLINK_ENCRYPT_LOGIN. Up to version 7.3, this parameter's default TRUE value prevented the password for the login user ID from being sent over the network (in the clear). Later versions automatically encrypt the password.
The following restrictions apply when using BYTE and TEXT data types:
An unsupported SQL function cannot be used in a SQL statement that accesses a column defined as Informix data type TEXT.
You cannot use SQL*Plus to select data from a column defined as Informix data type TEXT when the data is greater than 80 characters in length. Oracle Corporation recommends using Pro*C or Oracle Call Interface to access such data in a Informix database.
BYTE and TEXT data types must be NULLABLE for INSERT or UPDATE to work.
A table including a BYTE or TEXT column must have a unique index defined on the table or the table must have a separate column that serves as a primary key.
BYTE and TEXT data in a view cannot be accessed.
BYTE and TEXT data cannot be read through pass-through queries.
The gateway does not support the PL/SQL function COLUMN_VALUE_LONG of the DBMS_SQL package.
If you do not prefix a Informix database object with its schema name in a SQL statement within a PL/SQL block, the following error message occurs:
ORA-6550 PLS-201 Identifier table_name must be declared.
Change the SQL statement to include the schema name of the object.