Oracle Transparent Gateway Sybase Administrator's Guide
Release 8.1.6 for Windows NT

Part Number A80982-01

Library

Contents

Index

Go to previous page Go to next page

1
Release Information

This chapter contains information specific to this release of the Oracle Transparent Gateway for Sybase, and contains the following sections:

Product Set

This table lists the versions of the components included on the distribution CD-ROM. All components are at production level.

Product  Version Number 

Net8 Server 

8.1.6.0.0 

Net8 Client 

8.1.6.0.0 

Net8 Assistant 

8.1.6.0.0 

Net8 Configuration Assistant 

8.1.6.0.0 

Oracle Universal Installer 

1.7.0.18.0A 

Oracle Transparent Gateway for Sybase 

8.1.6.0.0 

System Requirements

This section describes the following:

Hardware Requirements

The following table summarizes the hardware requirements for the Oracle Transparent Gateway for Sybase.

Hardware Requirements 

Processor 

A Windows NT workstation running the required version of Windows NT 

Memory 

2.63MB of real memory is recommended for the first user to support the gateway. Each concurrent use of the gateway requires 0.26MB. The total real memory requirement for the concurrent use of the gateway also depends on these factors:

  • The SQL statement issued by the user

  • The number of cursors currently opened against Sybase

  • The number of columns in the table being accessed

 

CD-ROM Drive 

An internal or external CD-ROM drive 

Disk Space 

150MB of free disk space 

Software Requirements

The system software configuration described in this section is supported by Oracle Corporation as long as the underlying system software products are supported by their respective vendors. Verify the latest support status with your system software vendors.

The following table summarizes the software requirements for the Oracle Transparent Gateway for Sybase.

Software Requirements 

Operating System 

Windows NT Workstation Version 4.0, or Microsoft Windows NT Server Version 4.0 

Oracle database server 

Oracle8i Enterprise Edition Server Version 8.1.6

Oracle database server can reside on any supported platform 

Oracle Networking 

On gateway machine:

  • Net8 Server Version 8.1.6

  • Oracle Adapter for Named Pipes, SPX, or TCP/IP

On the Oracle database server machine:

  • Oracle Net8 Client 8.1.6

  • Oracle Adapter for Named Pipes, SPX, or TCP/IP

The Net8 products are included on the distribution CD-ROM.

Net8 or Net8 Client and the Oracle Adapter must be installed on the machine where the Oracle database server is installed. Net8 Server and the Oracle Adapter must be installed on the machine where the gateway is installed.  

Sybase 

Sybase Server or Client, Version 11.03, 11.5.1 or 11.9.2 is required. If Sybase Server is not on the same machine as the gateway, then Sybase Open client library Version 11.03 or 11.1.1 is required. 

Tested Configurations

The following table provides the tested configurations at Oracle, at the time of this document release. Oracle continues to provide support for the most recent releases of Oracle and non-Oracle systems in a timely manner. For current supported configuration information, please contact Oracle Support Services or visit http://www.oracle.com/gateways.

Gateway Configurations for the Oracle database server release 8.1.6 
Database  Gateway and Operating System 

Sybase Version 11.03 

tg4sybs release 8.1.6 running on Windows NT Version 4.0 SP3 or SP5 

Sybase Version 11.5.1 

tg4sybs release 8.1.6 running on Windows NT Version 4.0 SP3 or SP5 

Sybase Version 11.9.2 

tg4sybs release 8.1.6 running on Windows NT Version 4.0 SP3 or SP5 

Database Compatibility Issues for Sybase

Sybase and Oracle databases function differently in some areas, causing compatibility problems. The following compatibility issues are described in this section:

Chained Mode

The gateway supports the ANSI-standard chained mode. Sybase stored procedures must be written for this mode. Running in chained mode allows the gateway to extend the Oracle two-phase commit protection to transactions updating Oracle and Sybase databases.

Column Definitions

By default, a Sybase table column cannot contain null values unless NULL is specified in the column definition. In compliance with the ANSI standard, the Sybase database option "allow nulls by default" can be set to true to change the default column definition to NULL.

For an Oracle table, null values are allowed in a column unless NOT NULL is specified in the column definition.

Naming Rules

Naming rule issues include the following:

Rules for Naming Objects

Oracle and Sybase 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 quote marks, case sensitivity, and the use of alphanumeric characters can all be different.

See Also:

Oracle8i Reference and Sybase documentation. 

Case Sensitivity

The Oracle database server defaults to uppercase unless you surround identifiers with double quote characters. For example, to refer to a Sybase table called emp, enter the name with double quote characters, as follows:

SQL> SELECT * FROM "emp"@SYBS;

However, to refer to a Sybase table called emp owned by Scott from an Oracle application, enter the following:

SQL> SELECT * FROM "Scott"."emp"@SYBS;

If the Sybase 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"@SYBS;

or

SQL> SELECT * FROM scott."emp"@SYBS;

Oracle Corporation recommends that you surround all Sybase object names with double-quote characters and use the exact letter case for the object names as they appear in the Sybase data dictionary. This convention is not required when referring to the supported Oracle data dictionary tables or views listed in Appendix B, "Data Dictionary".

If existing applications cannot be changed according to these conventions, create views in Oracle to associate Sybase names to the correct letter case. For example, to refer to the Sybase 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"@SYBS;

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 Sybase data dictionary. You must be prepared to update the Oracle view definitions whenever the data definitions for the corresponding tables are changed in the Sybase database.

Data Types

Data type issues include the following:

Binary Literal Notation

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 the Sybase VARBINARY and BINARY data types (a 0x followed by hexadecimal digits surrounded by single quotes).

For example, the following statement is not supported:

SQL> INSERT INTO BINARY_TAB@SYBS VALUES ('0xff')

where BINARY_TAB contains a column of data type VARBINARY or BINARY. Use bind variables when inserting into or updating VARBINARY and BINARY data types.

Data Type Conversion

Sybase 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@SYBS WHERE DATE_COL = "1-JAN-1998";

To avoid problems with implicit conversions, add explicit conversions, as in the following:

SELECT DATE_COL FROM TEST@SYBS WHERE DATE_COL = TO_DATE("1-JAN-1998")

See Also:

"Data Type Conversion" for more information about restrictions on data types. 

Queries

Query issues include the following:

Row Selection

Sybase 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.

Empty Strings

Oracle processes an empty string in a SQL statement as a null value. Sybase processes an empty string as a single space. For example, the following statement:

SELECT "ename", "empno", "job" FROM "emp"@SYBS
WHERE "ename" = '';

is processed by Sybase as follows:

SELECT ename, empno, job FROM emp WHERE ename = ' '

The gateway passes the empty string to the Sybase database without any conversion. If you intended an empty string to represent a null value, Sybase does not process the statement that way; it uses a space value. 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 "ename", "empno", "job" FROM "emp"@SYBS
WHERE "ename" IS NULL;

The gateway returns an empty string to the Oracle database server as a NULL value. This applies only to columns defined with a VARCHAR data type.

Empty Bind Variables

The gateway passes empty bind variables to the Sybase database as a NULL value. This applies only to columns defined with a VARCHAR data type.

Locking

The locking model for a Sybase database differs significantly from the Oracle model. The gateway depends on the underlying Sybase behavior, so Oracle applications that access Sybase through the gateway can be affected by the following possible scenarios:

Known Restrictions

Oracle Transparent Gateway for Sybase, Version 8.1.6, is architecturally different from the earlier versions of the gateway. If you encounter incompatibility problems not listed in this section or in "Known Problems" on page 1-14, please contact Oracle Support Services. The following section describes the known restrictions and includes suggestions for dealing with them when possible:

The following restriction also applies:

Transactional Integrity

The gateway cannot guarantee transactional integrity in the following cases:

Transaction Capability

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 it is always the commit point site when the Sybase database is updated by the transaction.

See Also:

Oracle8i Distributed Database Systems for more information and restrictions of the COMMIT_CONFIRM mode. 

COMMIT or ROLLBACK in PL/SQL Cursor Loops Closes Open Cursors

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.

Stored Procedures

Changes issued through stored procedures that embed commits or rollbacks cannot be controlled by the Oracle transaction manager or Oracle COMMIT or ROLLBACK commands.

Stored procedures that return a result set can be executed, but the result set is skipped. Any output parameters and return values are returned.

Pass-Through Feature

DDL statements executed by Sybase using the gateway pass-through feature might fail if they are in a multi-statement transaction. Set the Sybase option "ddl in tran" to allow DDL statements in a transaction.

Oracle Corporation recommends that you place a DDL statement in its own transaction when executing such a statement with the pass-through feature. An explicit COMMIT must be issued after the DDL statement.

If the SQL statements being passed through the gateway result in an implicit commit at the Sybase database, the Oracle transaction manager is unaware of the commit and an Oracle ROLLBACK command cannot be used to roll back the transaction.

Sybase NCHAR and NVARCHAR Data Types

The gateway cannot select a column defined with a Sybase NCHAR or NVARCHAR data type.

SQL Syntax

This section lists restrictions on the following SQL syntax:

SELECT FOR UPDATE Statement

The SELECT FOR UPDATE statement is not supported.

WHERE CURRENT OF Clause

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.

CONNECT BY Clause

The gateway does not support the CONNECT BY clause in a SELECT statement.

Subqueries in UPDATE Statement

Subqueries in the SET clause of an UPDATE statement are not supported.

Subqueries can be specified in the WHERE clause of an UPDATE statement. Each subquery, however, must reference a Sybase table. For example, using the table GTW_EMP, the following statement results in a 10% salary increase for all employees working in the RESEARCH department:

SQL> UPDATE "GTW_EMP"@SYBS SET "SAL"="SAL" * 1.1
   2   WHERE "DEPTNO"=(SELECT "DEPTNO" FROM "GTW_DEPT"@SYBS
   3       WHERE "DNAME"='RESEARCH');

If "GTW_DEPT"@SYBS is replaced by "DEPT" in the subquery where DEPT is the same table but located in the Oracle database, the following error results after the statement is issued:

ORA-02025: All tables in the SQL statement must be at the remote database.

ROWID

The Oracle ROWID implementation is not supported.

Subqueries in INSERT Statement

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"@SYBS
SELECT a."empno" FROM "emp_source"@SYBS a,
"emp_source"@SYBS b WHERE b."empno"=9999

SQL*Plus COPY Command with Lowercase Table Names

The gateway does not support the SQL*Plus COPY command for lowercase table names.

Database Links

The gateway is not multithreaded and cannot support shared database links. Each gateway session spawns a separate gateway process and connections cannot be shared.

National Language Support

The gateway supports all single byte ASCII character sets and the following multibyte character sets:

Known Problems

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:

FLOAT Data Type

The FLOAT data type precision is (7).

VARBINARY Data Type

The VARBINARY data type is reported as BINARY.

Encrypted Format Login

The Oracle database server supports an Oracle initialization parameter, DBLINK_ENCRYPT_LOGIN. When this parameter is set to TRUE, the password for the login user ID is not sent over the network.

If this parameter is set to TRUE in the initialization parameter file used by the Oracle database server, you must change the setting to FALSE to allow Oracle to communicate with the gateway.

Aggregate Function with CREATE TABLE or CREATE VIEW Statement

The Oracle database server does not send the gateway a SELECT statement containing an aggregate function that is part of a CREATE TABLE or CREATE VIEW statement. For example, it does not send the following statement:

CREATE TABLE sum_calls_table AS 
SELECT SUM(calls_abandoned), SUM(calls_completed),
SUM(calls_failed) FROM monthly_calls@SYBS;

Instead, Oracle interprets what the SQL statement requests and sends the gateway a statement or statements to retrieve the data required for the request. After the data is retrieved, Oracle performs the aggregate function originally requested and passes the results to the application.

A solution to this problem is to use a different series of SQL statements. For example, instead of using the CREATE TABLE statement in the above example, use the following statements:

DROP TABLE sum_calls_table;
CREATE TABLE sum_calls_table (x1sum NUMBER, x2sum NUMBER,
x3sum NUMBER);
DECLARE
x1 NUMBER;
x2 NUMBER;
x3 NUMBER;
BEGIN
SELECT SUM(calls_abandoned), SUM(calls_completed),
SUM(calls_failed) INTO x1, x2, x3 FROM monthly_calls@SYBS;
INSERT INTO sum_calls_table VALUES (x1, x2, x3);
END;
/

Date Arithmetic

The following SQL expressions do not function correctly with the gateway:

date + number
number
+ date
date - number
date1 - date2

Statements with the above expressions are sent to the Sybase database without any translation. Since Sybase does not support these date arithmetic functions, the statements return an error.

Sybase IMAGE and TEXT Data Types

The following restrictions apply when using IMAGE and TEXT data types:

The gateway does not support the PL/SQL function COLUMN_VALUE_LONG of the DBMS_SQL package.

See Also:

Appendix A, "Supported SQL Syntax and Functions"

String Functions

If you concatenate numeric literals using the "||" or CONCAT operator when using the gateway to query a Sybase database, the result is an arithmetic addition. For example, the result of the following statement is 18:

SQL> SELECT 9 || 9 FROM DUAL@SYBS;

The result is 99 when using Oracle to query an Oracle database.

Schema Names and PL/SQL

If you do not prefix a Sybase 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.

Data Dictionary Views and PL/SQL

You cannot refer to data dictionary views in SQL statements that are inside a PL/SQL block.

Stored Procedures

Stored procedures with output parameters defined with a CHAR data type return output parameters with VARCHAR data types.

Stored procedures with input or output parameters defined with NUMERIC or DECIMAL data types that are passed with either a NULL value or no value for input will return output values without the fractional part. To prevent this from happening, always specify an input parameter value, even if it is not used.


Go to previous page Go to next page
Oracle
Copyright © 2001 Oracle Corporation.

All Rights Reserved.

Library

Contents

Index