PK
9Aoa, mimetypeapplication/epub+zipPK 9A iTunesMetadata.plistY
After the gateway is installed and configured, you can use the gateway to access SQL Server data, pass SQL Server commands from applications to the SQL Server database, perform distributed queries, and copy data.
This chapter contains the following sections:
The gateway can pass SQL Server commands or statements from the application to the SQL Server 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 SQL Server database, as follows:
DECLARE
num_rows INTEGER;
BEGIN
num_rows := DBMS_HS_PASSTHROUGH.EXECUTE_IMMEDIATE@MSQL('command');
END;
/
Where command cannot be one of the following:
BEGIN
TRANSACTION
COMMIT
ROLLBACK
SAVE
SHUTDOWN
RELEASE
SAVEPOINT
CONNECT
SQL Server tool commands
The DBMS_HS_PASSTHROUGH
package supports passing bind values and executing SELECT statements.
Note: TRUNCATE cannot be used in a pass-through statement. |
See Also: Oracle Database PL/SQL Packages and Types Reference and Chapter 3, Features of Oracle Database Gateways, of Oracle Database Heterogeneous Connectivity User's Guide for more information about theDBMS_HS_PASSTHROUGH package. |
Using the procedural feature, the gateway can execute stored procedures that are defined in the SQL Server database. It is not necessary to relink the gateway or define the procedure to the gateway, but the procedure's access privileges must permit access by the user that the gateway is logging in as.
See Also: Oracle Database Heterogeneous Connectivity User's Guide for more information about executing stored procedures. |
Standard PL/SQL statements are used to execute a stored procedure.
The gateway supports stored procedures in three mutually exclusive modes:
Normal mode: Have access to IN
/OUT
arguments only
Return value mode: Have a return value for all stored procedures
Resultset mode: Out values are available as last result set
This feature allows the gateway to optionally run in CHAR
Semantics mode. Rather than always describing SQL Server CHAR
columns as CHAR(n BYTE)
, this feature describes them as CHAR(n CHAR)
and VARCHAR(n CHAR)
. The concept is similar to Oracle database CHAR
Semantics. You need to specify HS_NLS_LENGTH_SEMANTICS=CHAR
gateway parameter to activate this option. Refer to Appendix D for more detail.
This feature optionally suppresses the ratio expansion from SQL Server database to Oracle database involving multi-byte character set. By default, Oracle gateways assume the worst ratio to prevent data being truncated or insufficient buffer size situation. However, if you have specific knowledge of your SQL Server database and do not want the expansion to occur, you can specify HS_KEEP_REMOTE_COLUMN_SIZE
parameter to suppress the expansion. Refer to Appendix D for more detail.
Besides full IPv6 support between Oracle databases and the gateway, IPv6 is also supported between this gateway and SQL Server database. Refer to the HS_FDS_CONNECT_INFO
parameter in Appendix D for more detail.
You can optionally choose to terminate long idle gateway sessions automatically with the gateway parameter HS_IDLE_TIMEOUT
. Specifically, when a gateway session is idle for more than the specified time limit, the gateway session is terminated with any pending update rolled back. Refer to the HS_IDLE_TIMEOUT
parameter in Appendix D for more detail.
User-defined functions in a remote non-Oracle database can be used in SQL statements.
See Also: Oracle Database Heterogeneous Connectivity User's Guide for more information about executing user-defined functions on a non-Oracle database. |
By default, all stored procedures and functions do not return a return value to the user. To enable return values, set the HS_FDS_PROC_IS_FUNC
parameter value to TRUE
.
See Also: Appendix D, "Initialization Parameters" for information about both editing the initialization parameter file and theHS_FDS_PROC_IS_FUNC parameter. |
Note: If you set theHS_FDS_PROC_IS_FUNC gateway initialization parameter to TRUE , you must change the syntax of the procedure execute statement for all existing stored procedures. |
In the following example, the employee name JOHN SMYTHE
is passed to the SQL Server stored procedure REVISE_SALARY
. The stored procedure retrieves the salary value from the SQL Server database to calculate a new yearly salary for JOHN SMYTHE
. The revised salary returned in RESULT
is used to update EMP
in a table of an Oracle database:
DECLARE INPUT VARCHAR2(15); RESULT NUMBER(8,2); BEGIN INPUT := 'JOHN SMYTHE'; RESULT := REVISE_SALARY@MSQL(INPUT); UPDATE EMP SET SAL = RESULT WHERE ENAME =: INPUT; END; /
The procedural feature automatically converts non-Oracle data types to and from PL/SQL data types.
The Oracle Database Gateway for SQL Server provides support for stored procedures which return result sets.
By default, all stored procedures and functions do not return a result set to the user. To enable result sets, set the HS_FDS_RESULTSET_SUPPORT
parameter value to TRUE
.
See Also: Appendix D, "Initialization Parameters" for information about both editing the initialization parameter file and theHS_FDS_RESULTSET_SUPPORT parameter. For further information about Oracle support for result sets in non-Oracle databases see Oracle Database Heterogeneous Connectivity User's Guide. |
Note: If you set theHS_FDS_RESULTSET_SUPPORT gateway initialization parameter to TRUE , then you must change the syntax of the procedure execute statement for all existing stored procedures, else errors will occur. |
When accessing stored procedures with result sets through the Oracle Database Gateway for SQL Server, you will be in the sequential mode of Heterogeneous Services.
The Oracle Database Gateway for SQL Server returns the following information to Heterogeneous Services during procedure description:
All the input arguments of the remote stored procedure
None of the output arguments
One out argument of type ref cursor (corresponding to the first result set returned by the stored procedure)
Client programs have to use the virtual package function DBMS_HS_RESULT_SET.GET_NEXT_RESULT_SET
to get the ref cursor for subsequent result sets. The last result set returned is the out argument from the procedure.
The limitations of accessing result sets are the following:
Result sets returned by a remote stored procedure have to be retrieved in the order in which they were placed on the wire
On execution of a stored procedure, all result sets returned by a previously executed stored procedure will be closed (regardless of whether the data has been completely retrieved or not)
In the following example, the SQL Server stored procedure is executed to fetch the contents of the emp
and dept
tables from SQL Server:
create procedure REFCURPROC (@arg1 varchar(255), @arg2 varchar(255) output) as select @arg2 = @arg1 select * from EMP select * from DEPT go
This stored procedure assigns the input parameter arg1 to the output parameter arg2, opens the query SELECT * FROM EMP
in ref cursor rc1, and opens the query SELECT * FROM DEPT
in ref cursor rc2.
The following example shows OCI program fetching from result sets in sequential mode:
OCIEnv *ENVH; OCISvcCtx *SVCH; OCIStmt *STMH; OCIError *ERRH; OCIBind *BNDH[3]; OraText arg1[20]; OraText arg2[255]; OCIResult *rset; OCIStmt *rstmt; ub2 rcode[3]; ub2 rlens[3]; sb2 inds[3]; OraText *stmt = (OraText *) "begin refcurproc@MSQL(:1,:2,:3); end;"; OraText *n_rs_stm = (OraText *) "begin :ret := DBMS_HS_RESULT_SET.GET_NEXT_RESULT_SET@MSQL; end;"; /* Prepare procedure call statement */ /* Handle Initialization code skipped */ OCIStmtPrepare(STMH, ERRH, stmt, strlen(stmt), OCI_NTV_SYNTAX, OCI_DEFAULT); /* Bind procedure arguments */ inds[0] = 0; strcpy((char *) arg1, "Hello World"); rlens[0] = strlen(arg1); OCIBindByPos(STMH, &BNDH[0], ERRH, 1, (dvoid *) arg1, 20, SQLT_CHR, (dvoid *) &(inds[0]), &(rlens[0]), &(rcode[0]), 0, (ub4 *) 0, OCI_DEFAULT); inds[1] = -1; OCIBindByPos(STMH, &BNDH[1], ERRH, 1, (dvoid *) arg2, 20, SQLT_CHR, (dvoid *) &(inds[1]), &(rlens[1]), &(rcode[1]), 0, (ub4 *) 0, OCI_DEFAULT); inds[2] = 0; rlens[2] = 0; OCIDescriptorAlloc(ENVH, (dvoid **) &rset, OCI_DTYPE_RSET, 0, (dvoid **) 0); OCIBindByPos(STMH, &BNDH[2], ERRH, 2, (dvoid *) rset, 0, SQLT_RSET, (dvoid *) &(inds[2]), &(rlens[2]), &(rcode[2]), 0, (ub4 *) 0, OCI_DEFAULT); /* Execute procedure */ OCIStmtExecute(SVCH, STMH, ERRH, 1, 0, (CONST OCISnapshot *) 0, (OCISnapshot *) 0, OCI_DEFAULT); /* Convert result set to statement handle */ OCIResultSetToStmt(rset, ERRH); rstmt = (OCIStmt *) rset; /* After this the user can fetch from rstmt */ /* Issue get_next_result_set call to get handle to next_result set */ /* Prepare Get next result set procedure call */ OCIStmtPrepare(STMH, ERRH, n_rs_stm, strlen(n_rs_stm), OCI_NTV_SYNTAX, OCI_DEFAULT); /* Bind return value */ OCIBindByPos(STMH, &BNDH[1], ERRH, 1, (dvoid *) rset, 0, SQLT_RSET, (dvoid *) &(inds[1]), &(rlens[1]), &(rcode[1]), 0, (ub4 *) 0, OCI_DEFAULT); /* Execute statement to get next result set*/ OCIStmtExecute(SVCH, STMH, ERRH, 1, 0, (CONST OCISnapshot *) 0, (OCISnapshot *) 0, OCI_DEFAULT); /* Convert next result set to statement handle */ OCIResultSetToStmt(rset, ERRH); rstmt = (OCIStmt *) rset; /* Now rstmt will point to the second result set returned by the remote stored procedure */ /* Repeat execution of get_next_result_set to get the output arguments */
Assume that the table loc_emp
is a local table exactly like the SQL Server emp
table. The same assumption applies for loc_dept
. The table outargs
has columns corresponding to the out
arguments of the SQL Server stored procedure.
create table outargs (outarg varchar2(255), retval number);
create or replace package rcpackage is type RCTYPE is ref cursor; end rcpackage; /
declare rc1 rcpackage.rctype; rec1 loc_emp%rowtype; rc2 rcpackage.rctype; rec2 loc_dept%rowtype; rc3 rcpackage.rctype; rec3 outargs%rowtype; out_arg varchar2(255); begin -- Execute procedure out_arg := null; refcurproc@MSQL('Hello World', out_arg, rc1); -- Fetch 20 rows from the remote emp table and insert them into loc_emp for i in 1 .. 20 loop fetch rc1 into rec1; insert into loc_emp (rec1.empno, rec1.ename, rec1.job, rec1.mgr, rec1.hiredate, rec1.sal, rec1.comm, rec1.deptno); end loop; -- Close ref cursor close rc1; -- Get the next result set returned by the stored procedure rc2 := dbms_hs_result_set.get_next_result_set@MSQL; -- Fetch 5 rows from the remote dept table and insert them into loc_dept for i in 1 .. 5 loop fetch rc2 into rec2; insert into loc_dept values (rec2.deptno, rec2.dname, rec2.loc); end loop; --Close ref cursor close rc2; -- Get the output arguments from the remote stored procedure -- Since we are in sequential mode, they will be returned in the -- form of a result set rc3 := dbms_hs_result_set.get_next_result_set@MSQL; -- Fetch them and insert them into the outargs table fetch rc3 into rec3; insert into outargs (rec3.outarg, rec3.retval); -- Close ref cursor close rc3; end; /
SQL Server and Oracle databases function differently in some areas, causing compatibility problems. The following compatibility issues are described in this section:
The gateway supports the ANSI-standard implicit transactions. SQL Server stored procedures must be written for this mode. Running implicit transactions allows the gateway to extend the Oracle two-phase commit protection to transactions updating Oracle and SQL Server databases.
By default, a SQL Server table column cannot contain null values unless NULL
is specified in the column definition. SQL Server assumes all columns cannot contain null values unless you set a SQL Server option to override this default.
For an Oracle table, null values are allowed in a column unless NOT NULL
is specified in the column definition.
Naming rule issues include the following:
Oracle and SQL Server 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.
The Oracle database defaults to uppercase unless you surround identifiers with double quote characters. For example, to refer to the SQL Server table called emp
, enter the name with double quote characters, as follows:
SQL> SELECT * FROM "emp"@MSQL;
However, to refer to the SQL Server table called emp
owned by Scott from an Oracle application, enter the following:
SQL> SELECT * FROM "Scott"."emp"@MSQL;
If the SQL Server 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"@MSQL;
Or
SQL> SELECT * FROM scott."emp"@MSQL;
Oracle recommends that you surround all SQL Server object names with double quote characters and use the exact letter case for the object names as they appear in the SQL Server 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 SQL Server names to the correct letter case. For example, to refer to the SQL Server 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"@MSQL;
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 SQL Server data dictionary. You must be prepared to update the Oracle view definitions whenever the data definitions for the corresponding tables are changed in the SQL Server database.
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 the SQL Server 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@MSQL 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.
The gateway does not support using bind variables to update columns of data type LONG
.
SQL Server 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@MSQL WHERE DATE_COL = "1-JAN-2004";
To avoid problems with implicit conversions, add explicit conversions, as in the following:
SELECT DATE_COL FROM TEST@MSQL WHERE DATE_COL = TO_DATE("1-JAN-2004")
Query issues include the following:
SQL Server 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.
Oracle processes an empty string in a SQL statement as a null value. SQL Server processes an empty string as an empty string.
When comparing an empty string the gateway passes literal empty strings to the SQL Server database without any conversion. If you intended an empty string to represent a null value, SQL Server 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"@MSQL where "ename" IS NULL;
Selecting an empty string
For VARCHAR
columns, the gateway returns an empty string to the Oracle database as NULL
value.
For CHAR
columns, the gateway returns the full size of the column with each character as empty space (' ').
For VARCHAR
bind variables, the gateway passes empty bind variables to the SQL Server database as a NULL
value.
The locking model for an SQL Server database differs significantly from the Oracle model. The gateway depends on the underlying SQL Server behavior, so the following possible scenarios can affect Oracle applications that access SQL Server through the gateway:
Read access might block write access
Write access might block read access
Statement-level read consistency is not guaranteed
See Also: SQL Server documentation for information about the SQL Server locking model. |
If you encounter incompatibility problems not listed in this section or in "Known Problems", contact Oracle Support Services. The following section describes the known restrictions and includes suggestions for dealing with them when possible:
Note: If you have any questions or concerns about the restrictions, contact Oracle Support Services. |
Accessing SQL Server has the limitation that one open statement or cursor is allowed for each connection. If a second statement or cursor needs to open in the same transaction to access SQL Server, it requires a new connection.
Because of this limitation multiple open statements or cursors within the same transaction can lock each other because they use different connections to SQL Server.
To avoid this restriction, issue a commit, or modify the logic, or both.
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 strongly recommends the following:
|
The gateway sets Autocommit Mode to Off when a connection is established to the SQL Server database.
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
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.
The Oracle transaction manager or Oracle COMMIT
or ROLLBACK
commands cannot contril changes issued through stored procedures that embed commits or rollbacks
When accessing stored procedures with result sets through the Oracle Database Gateway for SQL Server, you must work in the sequential mode of Heterogeneous Services.
When accessing stored procedures with multiple result sets through the Oracle Database Gateway for SQL Server, you must read all the result sets before continuing.
Output parameters of stored procedures must be initialized to an empty string.
If the SQL statements being passed through the gateway result in an implicit commit at the SQL Server database, the Oracle transaction manager is unaware of the commit and an Oracle ROLLBACK
command cannot be used to roll back the transaction.
SQL Server requires some DDL statements to be executed in their own transaction, and only one DDL statement can be executed in a given transaction.
If you use these DDL statements in a SQL Server stored procedure and you execute the stored procedure through the gateway using the procedural feature, or, if you execute the DDL statements through the gateway using the pass-through feature, an error condition might result. This is because the procedural feature and the pass-through feature of the gateway cannot guarantee that the DDL statements are executed in their own separate transaction.
The following SQL Server DDL statements can cause an error condition if you attempt to pass them with the gateway pass-through feature, or if you execute a SQL Server stored procedure that contains them:
Table 2-1 Restricted DDL Statements
Statement Name |
---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
See Also: SQL Server documentation for more information about DDL statements. |
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.
Bind variables and expressions are not supported as operands in string functions or mathematical functions, when part of subquery in an INSERT
, UPDATE
, or DELETE
SQL statement.
Due to a limitation in SQL Server, you cannot use parameters in subqueries.
Data dictionary tables and views in the SET
clause of an UPDATE
statement are not supported.
TO_DATE
is a reserved word and cannot be used as a database identifier name.
The EXPLAIN PLAN
statement is not supported.
SQL statements that require the gateway to callback to Oracle database would not be supported.
The following categories of SQL statements will result in a callback:
Any DML with a sub-select, which refers to a table in Oracle database. For example:
INSERT INTO emp@non_oracle SELECT * FROM oracle_emp;
Any DELETE
, INSERT
, UPDATE
or "SELECT... FOR UPDATE..."
SQL statement containing SQL functions or statements that needs to be executed at the originating Oracle database.
These SQL functions include USER
, USERENV
, and SYSDATE
, and the SQL statements are in selects of data from the originating Oracle database. For example:
DELETE FROM emp@non_oracle WHERE hiredate > SYSDATE;
SELECT ename FROM tkhoemp@non_oracle WHERE hiredate IN (SELECT hiredate FROM tkhoemp) FOR UPDATE OF empno;
Any SQL statement that involves a table in Oracle database, and a LONG
or LOB
column in a remote table. For example:
SELECT a.long1, b.empno FROM scott.table@non_oracle a, emp b WHERE a.id=b.empno;
SELECT a.long1, b.dummy FROM table_non@non_oracle a, dual b;
where a.long1
is a LONG
column.
The following restrictions apply to using functions:
Unsupported functions cannot be used in statements that refer to LONG
columns.
When negative numbers are used as the second parameter in a SUBSTR
function, incorrect results are returned. This is due to incompatibility between the Oracle SUBSTR
function and the equivalent in SQL Server.
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.
Oracle Database Gateway for SQL Server does not support CALLBACK
links. Trying a CALLBACK
link with the gateway will return the following error message:
ORA-02025: All tables in the SQL statement must be at the remote database
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 office for information about accessing the list.
The following known problems are described in this section:
The Oracle9i database (Release 9.2 and earlier) supported 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 Oracle9i database, you must change the setting to FALSE
, the default setting, to allow Oracle9i to communicate with the gateway.
In the current release, Oracle Database 11g, Release 11.2, the DBLINK_ENCRYPT_LOGIN
initialization parameter is obsolete, so you need not check it.
The following SQL expressions do not function correctly with the gateway:
date + number number + date date - number date1 - date2
Statements with the preceding expressions are sent to the SQL Server database without any translation. Since SQL Server does not support these date arithmetic functions, the statements return an error.
The following restrictions apply when using IMAGE
, TEXT
, and NTEXT
data types:
An unsupported SQL function cannot be used in a SQL statement that accesses a column defined as SQL Server data type IMAGE
, TEXT
, or NTEXT
.
You cannot use SQL*Plus to select data from a column defined as SQL Server data type IMAGE
, TEXT
, or NTEXT
when the data is greater than 80 characters in length. Oracle recommends using Pro*C or Oracle Call Interface to access such data in a SQL Server database.
IMAGE
, TEXT
, and NTEXT
data cannot be read through pass-through queries.
If a SQL statement is accessing a table including an IMAGE
, TEXT
, or NTEXT
column, the statement will be sent to SQL Server as two separate statements. One statement to access the IMAGE
, TEXT
or NTEXT
column, and a second statement for the other columns in the original statement.
The gateway does not support the PL/SQL function COLUMN_VALUE_LONG
of the DBMS_SQL
package.
See Also: Appendix B, "Supported SQL Syntax and Functions" for more information about restrictions on SQL syntax. |
If you concatenate numeric literals using the "||
" or CONCAT
operator when using the gateway to query a SQL Server database, the result is an arithmetic addition. For example, the result of the following statement is 18:
SQL> SELECT 9 || 9 FROM DUAL@MSQL;
The result is 99 when using Oracle to query an Oracle database.
If you do not prefix a SQL Server 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.
You cannot refer to data dictionary views in SQL statements that are inside a PL/SQL block.
The Oracle database initialization parameters in the init.ora
file are distinct from gateway initialization parameters. Set the gateway parameters in the initialization parameter file using an agent-specific mechanism, or set them in the Oracle data dictionary using the DBMS_HS
package. The gateway initialization parameter file must be available when the gateway is started.
This appendix contains a list of the gateway initialization parameters that can be set for each gateway and their description. It also describes the initialization parameter file syntax. It includes the following sections:
The syntax for the initialization parameter file is as follows:
The file is a sequence of commands.
Each command should start on a separate line.
End of line is considered a command terminator (unless escaped with a backslash).
If there is a syntax error in an initialization parameter file, none of the settings take effect.
Set the parameter values as follows:
[SET][PRIVATE] parameter=value
Where:
parameter
is an initialization parameter name. It is a string of characters starting with a letter and consisting of letters, digits and underscores. Initialization parameter names are case sensitive.
value
is the initialization parameter value. It is case sensitive. An initialization parameter value is either:
A string of characters that does not contain any backslashes, white space or double quotation marks (")
A quoted string beginning with a double quotation mark and ending with a double quotation mark. The following can be used inside a quoted string:
backslash (\) is the escape character
\n inserts a new line
\t inserts a tab
\" inserts a double quotation mark
\\ inserts a backslash
A backslash at the end of the line continues the string on the next line. If a backslash precedes any other character then the backslash is ignored.
For example, to enable tracing for an agent, set the HS_FDS_TRACE_LEVEL
initialization parameter as follows:
HS_FDS_TRACE_LEVEL=ON
SET
and PRIVATE
are optional keywords. You cannot use either as an initialization parameter name. Most parameters are needed only as initialization parameters, so you usually do not need to use the SET
or PRIVATE
keywords. If you do not specify either SET
or PRIVATE
, the parameter is used only as an initialization parameter for the agent.
SET
specifies that, in addition to being used as an initialization parameter, the parameter value is set as an environment variable for the agent process. Use SET
for parameter values that the drivers or non-Oracle system need as environment variables.
PRIVATE
specifies that the initialization parameter should be private to the agent and should not be uploaded to the Oracle database. Most initialization parameters should not be private. If, however, you are storing sensitive information like a password in the initialization parameter file, then you may not want it uploaded to the server because the initialization parameters and values are not encrypted when uploaded. Making the initialization parameters private prevents the upload from happening and they do not appear in dynamic performance views. Use PRIVATE
for the initialization parameters only if the parameter value includes sensitive information such as a user name or password.
SET PRIVATE
specifies that the parameter value is set as an environment variable for the agent process and is also private (not transferred to the Oracle database, not appearing in dynamic performance views or graphical user interfaces).
This section lists all the initialization file parameters that can be set for the Oracle Database Gateway for SQL Server. They are as follows:
The following sections describe all the initialization file parameters that can be set for gateways.
Property | Description |
---|---|
Default value | None |
Range of values | Not applicable |
Specifies the remote functions that can be referenced in SQL statements. The value is a list of remote functions and their owners, separated by semicolons, in the following format:
owner_name.function_name
For example:
owner1.A1;owner2.A2;owner3.A3
If an owner name is not specified for a remote function, the default owner name becomes the user name used to connect to the remote database (specified when the Heterogeneous Services database link is created or taken from user session if not specified in the DB link).
The entries for the owner names and the function names are case sensitive.
Property | Description |
---|---|
Default value | WORLD |
Range of values | 1 to 199 characters |
Specifies a unique network sub-address for a non-Oracle system. The HS_DB_DOMAIN
initialization parameter is similar to the DB_DOMAIN
initialization parameter, described in the Oracle Database Reference. The HS_DB_DOMAIN
initialization parameter is required if you use the Oracle Names server. The HS_DB_NAME
and HS_DB_DOMAIN
initialization parameters define the global name of the non-Oracle system.
Note: TheHS_DB_NAME and HS_DB_DOMAIN initialization parameters must combine to form a unique address in a cooperative server environment. |
Property | Description |
---|---|
Default value | 01010101 |
Range of values | 1 to 16 hexadecimal characters |
Specifies a unique hexadecimal number identifying the instance to which the Heterogeneous Services agent is connected. This parameter's value is used as part of a transaction ID when global name services are activated. Specifying a nonunique number can cause problems when two-phase commit recovery actions are necessary for a transaction.
Property | Description |
---|---|
Default value | HO |
Range of values | 1 to 8 characters |
Specifies a unique alphanumeric name for the data store given to the non-Oracle system. This name identifies the non-Oracle system within the cooperative server environment. The HS_DB_NAME
and HS_DB_DOMAIN
initialization parameters define the global name of the non-Oracle system.
Property | Description |
---|---|
Default value | 100 |
Range of values | 1 to 4000 |
Specifies the maximum number of entries in the describe cache used by Heterogeneous Services. This limit is known as the describe cache high water mark. The cache contains descriptions of the mapped tables that Heterogeneous Services reuses so that it does not have to re-access the non-Oracle data store.
If you are accessing many mapped tables, increase the high water mark to improve performance. Increasing the high water mark improves performance at the cost of memory usage.
Property | Description |
---|---|
Default value | System-specific |
Range of values | Any valid language name (up to 255 characters) |
Provides Heterogeneous Services with character set, language, and territory information of the non-Oracle data source. The value must use the following format:
language[_territory.character_set]
Note: The globalization support initialization parameters affect error messages, the data for the SQL Service, and parameters in distributed external procedures. |
Ideally, the character sets of the Oracle database and the non-Oracle data source are the same. In almost all cases, HS_LANGUAGE
should be set exactly the same as Oracle database character set for optimal character set mapping and performance. If they are not the same, Heterogeneous Services attempts to translate the character set of the non-Oracle data source to the Oracle database character set, and back again. The translation can degrade performance. In some cases, Heterogeneous Services cannot translate a character from one character set to another.
Note: The specified character set must be a superset of the operating system character set on the platform where the agent is installed. |
As more Oracle databases and non-Oracle databases use Unicode as database character sets, it is preferable to also run the gateway in Unicode character set. To do so, you must set HS_LANGUAGE=AL32UTF8
. However, when the gateway runs on Windows, the Microsoft ODBC Driver Manager interface can exchange data only in the double-byte character set, UCS2. This results in extra ratio expansion of described buffer and column sizes. Refer to HS_FDS_REMOTE_DB_CHARSET for instruction on how to adjust to correct sizes.
The language component of the HS_LANGUAGE
initialization parameter determines:
Day and month names of dates
AD, BC, PM, and AM symbols for date and time
Default sorting mechanism
Note that Oracle does not determine the language for error messages for the generic Heterogeneous Services messages (ORA-25000
through ORA-28000
). These are controlled by the session settings in the Oracle database.
The territory clause specifies the conventions for day and week numbering, default date format, decimal character and group separator, and ISO and local currency symbols. Note that the level of globalization support between the Oracle database and the non-Oracle data source depends on how the gateway is implemented.
Property | Description |
---|---|
Default value | 64 KB |
Range of values | Any value up to 2 GB |
Sets the size of the piece of LONG
data being transferred. A smaller piece size means less memory requirement, but more round-trips to fetch all the data. A larger piece size means fewer round-trips, but more of a memory requirement to store the intermediate pieces internally. Thus, the initialization parameter can be used to tune a system for the best performance, with the best trade-off between round-trips and memory requirements, and network latency or response time.
Property | Description |
---|---|
Default value | 50 |
Range of values | 1 to the value of Oracle's OPEN_CURSORS initialization parameter |
Defines the maximum number of cursors that can be open on one connection to a non-Oracle system instance.
The value never exceeds the number of open cursors in the Oracle database. Therefore, setting the same value as the OPEN_CURSORS
initialization parameter in the Oracle database is recommended.
Property | Description |
---|---|
Default value | ON |
Range of values | OFF or ON |
Controls whether Heterogeneous Services attempts to optimize performance of data transfer between the Oracle database and the Heterogeneous Services agent connected to the non-Oracle data store.
The following values are possible:
OFF
disables reblocking of fetched data so that data is immediately sent from agent to server.
ON
enables reblocking, which means that data fetched from the non-Oracle system is buffered in the agent and is not sent to the Oracle database until the amount of fetched data is equal to or higher than the value of HS_RPC_FETCH_SIZE
initialization parameter. However, any buffered data is returned immediately when a fetch indicates that no more data exists or when the non-Oracle system reports an error.
Property | Description |
---|---|
Default value | 50000 |
Range of values | 1 to 10000000 |
Tunes internal data buffering to optimize the data transfer rate between the server and the agent process.
Increasing the value can reduce the number of network round-trips needed to transfer a given amount of data, but also tends to increase data bandwidth and to reduce latency as measured between issuing a query and completion of all fetches for the query. Nevertheless, increasing the fetch size can increase latency for the initial fetch results of a query, because the first fetch results are not transmitted until additional data is available.
Property | Description |
---|---|
Default value for '[+|-]hh:mm' | Derived from the NLS_TERRITORY initialization parameter |
Range of values for '[+|-]hh:mm' | Any valid datetime format mask |
Specifies the default local time zone displacement for the current SQL session. The format mask, [+|-]hh:mm, is specified to indicate the hours and minutes before or after UTC (Coordinated Universal Time—formerly Greenwich Mean Time). For example:
HS_TIME_ZONE = [+ | -] hh:mm
Property | Description |
---|---|
Default Value | COMMIT_CONFIRM |
Range of Values | COMMIT_CONFIRM , READ_ONLY , SINGLE_SITE , READ_ONLY_AUTOCOMMIT , SINGLE_SITE_AUTOCOMMIT |
Specifies the type of transaction model that is used when the non-Oracle database is updated by a transaction.
The following values are possible:
COMMIT_CONFIRM
provides read and write access to the non-Oracle database and allows the gateway to be part of a distributed update. To u se the commit-confirm model, the following items must be created in the non-Oracle database:
Transaction log table. The default table name is HS_TRANSACTION_LOG
. A different name can be set using the HS_FDS_TRANSACTION_LOG
parameter. The transaction log table must be granted SELECT
, DELETE
, and INSERT
privileges set to public.
Recovery account. The account name is assigned with the HS_FDS_RECOVERY_ACCOUNT
parameter.
Recovery account password. The password is assigned with the HS_FDS_RECOVERY_PWD
parameter.
READ_ONLY
provides read access to the non-Oracle database.
SINGLE_SITE
provides read and write access to the non-Oracle database. However, the gateway cannot participate in distributed updates.
READ_ONLY_AUTOCOMMIT
provides read only access to the non-Oracle database that does not use logging.
SINGLE_SITE_AUTOCOMMIT
provides read and write access to the non-Oracle database without logging. The gateway cannot participate in distributed updates. Moreover, any update to the non-Oracle database is committed immediately.
Property | Description |
---|---|
Default value | None |
Range of values | Valid parameter file names |
Use the IFILE
initialization parameter to embed another initialization file within the current initialization file. The value should be an absolute path and should not contain environment variables. The three levels of nesting limit do not apply.
Property | Description |
---|---|
Default Value | None |
Range of Values | Not applicable |
HS_FDS_CONNECT_INFO
that describes the connection to the non-Oracle system.
The default initialization parameter file already has an entry for this parameter. The syntax for HS_FDS_CONNECT_INFO
for the gateway is as follows:
For UNIX:
HS_FDS_CONNECT_INFO=host_name[[:port_number]|/[instance_name]][/database_name]
where, host_name
is the host name or IP address of the machine hosting the SQL Server database, port_number
is the port number of the SQL Server, instance_name
is the instance of SQL Server running on the machine, and database_name
is the SQL Server database name.
Either of the variables port_number
or instance_name
can be used, but not both together. Optionally, they both can be omitted. The variable database_name
is always optional. The slash (/
) is required when a particular value is omitted. For example, all of the following entries are valid:
HS_FDS_CONNECT_INFO=host_name/instance_name/database_name HS_FDS_CONNECT_INFO=host_name//database_name HS_FDS_CONNECT_INFO=host_name:port_name//database_name HS_FDS_CONNECT_INFO=host_name/instance_name HS_FDS_CONNECT_INFO=host_name
For Windows:
HS_FDS_CONNECT_INFO= host_name/[instance_name][/database_name]
where, host_name
is the host name or IP address of the machine hosting the SQL Server database, instance_name
is the instance of SQL Server running on the machine, and database_name
is the SQL Server database name.
Both instance_name
and database_name
are optional. If instance_name
is omitted and database_name
is provided, the slash (/
) is required. This can be shown as follows:
HS_FDS_CONNECT_INFO= host_name//database_name
This release supports IPv6 format, so you can enter IPv6 format in place of hostname
, but you need to wrap square brackets around the IPv6 specification.
For example,
HS_FDS_CONNECT_INFO=[2001:0db8:20c:f1ff:fec6:38af]:port_number/…
Property | Description |
---|---|
Default Value | FALSE |
Range of Values | TRUE , FALSE |
Enables return values from functions. By default, all stored procedures and functions do not return a return value to the user.
Note: If you set this initialization parameter, you must change the syntax of the procedure execute statement for all existing stored procedures to handle return values. |
Property | Description |
---|---|
Default Value | RECOVER |
Range of values | Any valid user ID |
Specifies the name of the recovery account used for the commit-confirm transaction model. An account with user name and password must be set up at the non-Oracle system. For more information about the commit-confirm model, see the HS_TRANSACTION_MODEL
parameter.
The name of the recovery account is case sensitive.
Property | Description |
---|---|
Default Value | RECOVER |
Range of values | Any valid password |
Specifies the password of the recovery account used for the commit-confirm transaction model set up at the non-Oracle system. For more information about the commit-confirm model, see the HS_TRANSACTION_MODEL
parameter.
The name of the password of the recovery account is case sensitive.
Property | Description |
---|---|
Default Value | FALSE |
Range of Values | TRUE , FALSE |
Enables Oracle Database Gateway for SQL Server to treat SINGLE FLOAT PRECISION
fields as DOUBLE FLOAT PPRECISION
fields.
Property | Description |
---|---|
Default Value | FALSE |
Range of Values | TRUE , FALSE |
Enables result sets to be returned from stored procedures. By default, all stored procedures do not return a result set to the user.
Note: If you set this initialization parameter, you must do the following:
|
Property | Description |
---|---|
Default Value | OFF |
Range of values | OFF , ON , DEBUG |
Specifies whether error tracing is turned on or off for gateway connectivity.
The following values are valid:
OFF disables the tracing of error messages.
ON enables the tracing of error messages that occur when you encounter problems. The results are written by default to a gateway log file in LOG directory where the gateway is installed.
DEBUG enables the tracing of detailed error messages that can be used for debugging.
Property | Description |
---|---|
Default Value | HS_TRANSACTION_LOG |
Range of Values | Any valid table name |
Specifies the name of the table created in the non-Oracle system for logging transactions. For more information about the transaction model, see the HS_TRANSACTION_MODEL
parameter.
Property | Description |
---|---|
Default Value | 100 |
Range of Values | Any integer between 1 and 1000 |
Syntax | HS_FDS_FETCH_ROWS= num |
HS_FDS_FETCH_ROWS
specifies the fetch array size. This is the number of rows to be fetched from the non-Oracle database and to return to Oracle database at one time. This parameter will be affected by the HS_RPC_FETCH_SIZE
and HS_RPC_FETCH_REBLOCKING
parameters.
Property | Description |
---|---|
Default Value | 0 (no timeout) |
Range of Values | 0-9999 (minutes) |
Syntax | HS_IDLE_TIMEOUT= num |
This feature is only available for Oracle Net TCP protocol. When there is no activity for a connected gateway session for this specified time period, the gateway session would be terminated automatically with pending update (if any) rolled back.
Property | Description |
---|---|
Default Value | BYTE |
Range of Values | BYTE | CHAR |
Syntax | HS_NLS_LENGTH_SEMANTICS = { BYTE | CHAR } |
This release of gateway has Character Semantics functionality equivalent to the Oracle Database Character Semantics, that is, NLS_LENGTH_SEMANTICS
. When HS_NLS_LENGTH_SEMANTICS
is set to CHAR
, the (VAR)CHAR
columns of SQL Server database are to be interpreted as having CHAR
semantics. The only situation the gateway does not honor the HS_NLS_LENGTH_SEMANTICS=CHAR
setting is when both Oracle database and the gateway are on the same multi-byte character set
Property | Description |
---|---|
Default Value | OFF |
Range of Values | OFF | LOCAL | REMOTE | ALL |
Syntax | HS_KEEP_REMOTE_COLUMN_SIZE = OFF | LOCAL | REMOTE | ALL |
Parameter type | String |
HS_KEEP_REMOTE_COLUMN_SIZE
specifies whether to suppress ratio expansion when computing the length of (VAR)CHAR
datatypes during data conversion from the non-Oracle database to the gateway, and then to the Oracle database. When it is set to REMOTE
, the expansion is suppressed between the non-Oracle database and the gateway. When it is set to LOCAL
, the expansion is suppressed between the gateway and the Oracle database. When it is set to ALL
, the expansion is suppressed from the non-Oracle database to the Oracle database.
When the parameter is set, the expansion is suppressed when reporting the remote column size, calculating the implicit resulting buffer size, and instantiating in the local Oracle database. This has effect only for remote column size from non-Oracle database to Oracle database. If the gateway runs on Windows and HS_LANGUAGE=AL32UTF8
, then you must not specify this parameter, as it would influence other ratio related parameter operation. It has no effect for calculating ratio for data moving from Oracle database to non-Oracle database through gateway during INSERT
, UPDATE
, or DELETE
.
Property | Description |
---|---|
Default Value | None |
Range of values | Not applicable |
Syntax | HS_FDS_REMOTE_DB_CHARSET |
This parameter is valid only when HS_LANGUAGE
is set to AL32UTF8
and the gateway runs on Windows. As more Oracle databases and non-Oracle databases use Unicode as database character sets, it is preferable to also run the gateway in Unicode character set. To do so, you must set HS_LANGUAGE=AL32UTF8
. However, when the gateway runs on Windows, the Microsoft ODBC Driver Manager interface can exchange data only in the double-byte character set, UCS2. This results in extra ratio expansion of described buffer and column sizes. To compensate, the gateway can re-adjust the column size if HS_FDS_REMOTE_DB_CHARSET
is set to the corresponding non-Oracle database character set. For example, HS_FDS_REMOTE_DB_CHARSET=KO16KSC5601
.
Property | Description |
---|---|
Default Value | TRUE |
Range of values | {TRUE|FALSE} |
Syntax | HS_FDS_SUPPORT_STATISTICS= {TRUE|FALSE} |
We gather statistics from the non-Oracle database by default. You can choose to disable the gathering of remote database statistics by setting the HS_FDS_SUPPORT_STATISTICS
parameter to FALSE
.
Property | Description |
---|---|
Default Value | FALSE |
Range of values | {TRUE|FALSE} |
Syntax | HS_FDS_RSET_RETURN_ROWCOUNT= {TRUE|FALSE} |
When set to TRUE
, the gateway returns the row counts of DML statements that are executed inside a stored procedure. The row count is returned as a single row, single column result set of type signed integer.
When set to FALSE
, the gateway skips the row counts of DML sta0tements that are executed inside a stored procedure. This is the default behavior, and it is the behavior of 11.1 and older gateways.
Property | Description |
---|---|
Default Value | 64 |
Range of values | {64|32} |
Syntax | HS_FDS_SQLLEN_INTERPRETATION= {64|32} |
This parameter is only valid for 64 bit platforms. ODBC standard specifies SQLLEN
(of internal ODBC construct) being 64 bit on 64 bit platforms, but some ODBC driver managers and drivers violate this convention, and implement it as 32 bit. In order for the gateway to compensate their behavior, you need to specify HS_FDS_SQLLEN_INTERPRETATION=32
if you use these types of driver managers and driver.
User's Guide,
11g Release 2 (11.2)
E12069-02
January 2012
Oracle Database Gateway for SQL Server User's Guide, 11g Release 2 (11.2)
E12069-02
Copyright © 2002, 2012, Oracle and/or its affiliates. All rights reserved.
Primary Author: Maitreyee Chaliha
Contributor: Vira Goorah, Juan Pablo Ahues-Vasquez, Peter Castro, Charles Benet, Peter Wong, and Govind Lakkoju
This software and related documentation are provided under a license agreement containing restrictions on use and disclosure and are protected by intellectual property laws. Except as expressly permitted in your license agreement or allowed by law, you may not use, copy, reproduce, translate, broadcast, modify, license, transmit, distribute, exhibit, perform, publish, or display any part, in any form, or by any means. Reverse engineering, disassembly, or decompilation of this software, unless required by law for interoperability, is prohibited.
The information contained herein is subject to change without notice and is not warranted to be error-free. If you find any errors, please report them to us in writing.
If this is software or related documentation that is delivered to the U.S. Government or anyone licensing it on behalf of the U.S. Government, the following notice is applicable:
U.S. GOVERNMENT RIGHTS Programs, software, databases, and related documentation and technical data delivered to U.S. Government customers are "commercial computer software" or "commercial technical data" pursuant to the applicable Federal Acquisition Regulation and agency-specific supplemental regulations. As such, the use, duplication, disclosure, modification, and adaptation shall be subject to the restrictions and license terms set forth in the applicable Government contract, and, to the extent applicable by the terms of the Government contract, the additional rights set forth in FAR 52.227-19, Commercial Computer Software License (December 2007). Oracle America, Inc., 500 Oracle Parkway, Redwood City, CA 94065.
This software or hardware is developed for general use in a variety of information management applications. It is not developed or intended for use in any inherently dangerous applications, including applications that may create a risk of personal injury. If you use this software or hardware in dangerous applications, then you shall be responsible to take all appropriate fail-safe, backup, redundancy, and other measures to ensure its safe use. Oracle Corporation and its affiliates disclaim any liability for any damages caused by use of this software or hardware in dangerous applications.
Oracle and Java are registered trademarks of Oracle and/or its affiliates. Other names may be trademarks of their respective owners.
Intel and Intel Xeon are trademarks or registered trademarks of Intel Corporation. All SPARC trademarks are used under license and are trademarks or registered trademarks of SPARC International, Inc. AMD, Opteron, the AMD logo, and the AMD Opteron logo are trademarks or registered trademarks of Advanced Micro Devices. UNIX is a registered trademark of The Open Group.
This software or hardware and documentation may provide access to or information on content, products, and services from third parties. Oracle Corporation and its affiliates are not responsible for and expressly disclaim all warranties of any kind with respect to third-party content, products, and services. Oracle Corporation and its affiliates will not be responsible for any loss, costs, or damages incurred due to your access to or use of third-party content, products, or services.
This chapter introduces the challenge faced by organizations when running several different database systems. It briefly covers Heterogeneous Services, the technology that the Oracle Database Gateway for SQL Server is based on.
To get a good understanding of generic gateway technology, Heterogeneous Services, and how Oracle Database Gateways fit in the picture, reading Oracle Database Heterogeneous Connectivity User's Guide first is highly recommended.
This chapter contains the following sections:
Heterogeneous data access is a problem that affects a lot of companies. A lot of companies run several different database systems. Each of these systems stores data and has a set of applications that run against it. Consolidation of this data in one database system is often hard-in large part because many of the applications that run against one database may not have an equivalent that runs against another. Until such time as migration to one consolidated database system is made feasible, it is necessary for the various heterogeneous database systems to interoperate.
Oracle Database Gateways provide the ability to transparently access data residing in a non-Oracle system from an Oracle environment. This transparency eliminates the need for application developers to customize their applications to access data from different non-Oracle systems, thus decreasing development efforts and increasing the mobility of the application. Applications can be developed using a consistent Oracle interface for both Oracle and SQL Server.
Gateway technology is composed of two parts: a component that has the generic technology to connect to a non-Oracle system, which is common to all the non-Oracle systems, called Heterogeneous Services, and a component that is specific to the non-Oracle system that the gateway connects to. Heterogeneous Services, in conjunction with the Oracle Database Gateway agent, enables transparent access to non-Oracle systems from an Oracle environment.
Heterogeneous Services provides the generic technology for connecting to non-Oracle systems. As an integrated component of the database, Heterogeneous Services can exploit features of the database, such as the powerful SQL parsing and distributed optimization capabilities.
Heterogeneous Services extend the Oracle SQL engine to recognize the SQL and procedural capabilities of the remote non-Oracle system and the mappings required to obtain necessary data dictionary information. Heterogeneous Services provides two types of translations: the ability to translate Oracle SQL into the proper dialect of the non-Oracle system as well as data dictionary translations that displays the metadata of the non-Oracle system in the local format. For situations where no translations are available, native SQL can be issued to the non-Oracle system using the pass-through feature of Heterogeneous Services.
Heterogeneous Services also maintains the transaction coordination between Oracle and the remote non-Oracle system, such as providing the two-phase commit protocol to ensure distributed transaction integrity, even for non-Oracle systems that do not natively support two-phase commit.
See Also: Oracle Database Heterogeneous Connectivity User's Guide for more information about Heterogeneous Services. |
The capabilities, SQL mappings, data type conversions, and interface to the remote non-Oracle system are contained in the gateway. The gateway interacts with Heterogeneous Services to provide the transparent connectivity between Oracle and non-Oracle systems.
The gateway can be installed on any machine independent of the Oracle or non-Oracle database. It can be the same machine as the Oracle database or on the same machine as the SQL Server database or on a third machine as a standalone.
The following case studies for SQL Server demonstrate some of the features of the Oracle Database Gateway. You can verify that the gateway is installed and operating correctly by using the demonstration files included in the distribution media.
The demonstration files are automatically copied to disk when the gateway is installed.
This chapter contains the following sections:
The cases illustrate:
A simple query (Case 1)
A more complex query (Case 2)
Joining SQL Server tables (Case 3)
Write capabilities (Case 4)
A data dictionary query (Case 5)
The pass-through feature (Case 6)
Executing stored procedures (Case 7)
The installation media contains the following:
Demonstration files
One SQL script file that creates the demonstration tables and stored procedures in the SQL Server database
One SQL script file that drops the demonstration tables and stored procedures from the SQL Server database
After a successful gateway installation, use the demonstration files stored in the directory ORACLE_HOME\dg4msql\demo
where ORACLE_HOME
is the directory under which the gateway is installed. The directory contains the following demonstration files:
The case studies assume these requirements have been met:
The gateway demonstration tables and stored procedures are installed in the SQL Server database
The Oracle database has an account named SCOTT
with a password of TIGER
The Oracle database has a database link called GTWLINK
(set up as public or private to the user SCOTT
) which connects the gateway to a SQL Server database as SCOTT
with password TIGER2
For example, you can create the database link as follows:
SQL> CREATE DATABASE LINK GTWLINK CONNECT TO SCOTT 2 IDENTIFIED BY TIGER2 USING 'GTWSID';
Oracle Net Services is configured correctly and running
The case studies are based on the GTW_EMP
, GTW_DEPT
, and GTW_SALGRADE
tables and the stored procedures InsertDept
and GetDept
. If the demonstration tables and stored procedures have not been created in the SQL Server database, use the bldmsql.sql
script to create them. Enter the following:
> isql -USCOTT -PTIGER2 -ibldmsql.sql
The script creates the demonstration tables and stored procedures in the SQL Server database accordingly:
CREATE TABLE GTW_EMP ( EMPNO SMALLINT NOT NULL ENAME VARCHAR(10), JOB VARCHAR(9), MGR SMALLINT, HIREDATE DATETIME, SAL NUMERIC(7,2), COMM NUMERIC(7,2), DEPTNO SMALLINT) go CREATE TABLE GTW_DEPT ( DEPTNO SMALLINT NOT NULL, DNAME VARCHAR(14), LOC VARCHAR(13)) go CREATE TABLE GTW_SALGRADE ( GRADE MONEY, LOSAL NUMERIC(9,4), HISAL NUMERIC(9,4)) go DROP PROCEDURE InsertDept go CREATE PROCEDURE InsertDept (@dno INTEGER, @dname VARCHAR(14), @loc VARCHAR(13)) AS INSERT INTO GTW_DEPT VALUES (@dno, @dname, @loc) go DROP PROCEDURE GetDept go CREATE PROCEDURE GetDept (@dno INTEGER, @dname VARCHAR(14) OUTPUT) AS SELECT @dname=DNAME FROM GTW_DEPT WHERE DEPTNO=@dno go
The following table definitions use information retrieved by the SQL*PLUS DESCRIBE
command:
GTW_EMP
Name Null? Type ------------------------------- -------- ---- EMPNO NOT NULL NUMBER(5) ENAME VARCHAR2(10) JOB VARCHAR2(9) MGR NUMBER(5) HIREDATE DATE SAL NUMBER(7,2) COMM NUMBER(7,2) DEPTNO NUMBER(5)
GTW_DEPT
Name Null? Type ------------------------------- -------- ---- DEPTNO NOT NULL NUMBER(5) DNAME VARCHAR2(14) LOC VARCHAR2(13)
GTW_SALGRADE
Name Null? Type ------------------------------- -------- ---- GRADE NUMBER(19,4) LOSAL NUMBER(9,4) HISAL NUMBER(9,4)
The contents of the SQL Server tables are:
GTW_EMP
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO ----- ----- --- --- -------- --- ---- ------ 7369 SMITH CLERK 7902 17-DEC-80 800 20 7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30 7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30 7566 JONES MANAGER 7839 02-APR-81 2975 20 7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30 7698 BLAKE MANAGER 7839 01-MAY-81 2850 30 7782 CLARK MANAGER 7839 09-JUN-81 2450 10 7788 SCOTT ANALYST 7566 09-DEC-82 3000 20 7839 KING PRESIDENT 17-NOV-81 5000 10 7844 TURNER SALESMAN 7698 08-SEP-81 1500 0 30 7876 ADAMS CLERK 7788 12-JAN-83 1100 20 7900 JAMES CLERK 7698 03-DEC-81 950 30 7902 FORD ANALYST 7566 03-DEC-81 3000 20 7934 MILLER CLERK 7782 23-JAN-82 1300 10
GTW_DEPT
DEPTNO DNAME LOC ----- -------------- -------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON
GTW_SALGRADE
GRADE LOSAL HISAL ------ ------ ----- 1 700 1200 2 1201 1400 3 1401 2000 4 2001 3000 5 3001 9999
Case 1 demonstrates the following:
A simple query
A simple query retrieving full date information
The first query retrieves all the data from GTW_DEPT
and confirms that the gateway is working correctly. The second query retrieves all the data from GTW_EMP
including the time portion of the hire date because the default date format was set to DD-MON-YY HH24:MM:SS
for the session by an ALTER SESSION
command.
Case 2 demonstrates the following:
The functions SUM(
expression
)
and NVL
(
expr1, expr2
)
in the SELECT
list
The GROUP BY
and HAVING
clauses
This query retrieves the departments from GTW_EMP
whose total monthly expenses are higher than $10,000
.
Case 3 demonstrates the following:
Joins between SQL Server tables
Subselects
The query retrieves information from three SQL Server tables and relates the employees to their department name and salary grade, but only for those employees earning more than the average salary.
Case 4 is split into three cases and demonstrates the following:
Case 4a demonstrates bind values and subselect. All employees in department 20
and one employee, WARD
, in department 30
are deleted.
Case 4b provides an example of a simple UPDATE
statement. In this example, employees are given a $100
a month salary increase.
Case 5 demonstrates data dictionary mapping. It retrieves all the tables and views that exist in the SQL Server database that begin with GTW
.
Case 6 demonstrates the gateway pass-through feature which allows an application to send commands or statements to SQL Server.
This case demonstrates:
A pass-through UPDATE
statement using bind variables
A pass-through SELECT
statement
Case 6a provides an example of a pass-through UPDATE
statement with bind variables. In this example, the salary for EMPNO
7934
is set to 4000
.