Oracle Provider for OLE DB Developer's Guide Release 9.2 Part Number A95498-01 |
|
This chapter describes components of Oracle Provider for OLE DB (OraOLEDB) and how to use the components to develop OLE DB consumer applications.
This chapter contains these topics:
The following sections describe provider-specific features of OraOLEDB:
Additional provider-specific information is provided in Appendix A, "Provider-Specific Information".
A data source object in OraOLEDB is responsible for establishing the first connection to the Oracle database. To establish the initial connection, the consumer must use the CoCreateInstance
function to create an instance of the data source object. This function requires important information about the provider: class ID of the provider and executable context. The class ID of OraOLEDB is CLSID_OraOLEDB
.
OraOLEDB is an in-process server. When calling CoCreateInstance
, use the CLSCTX_INPROC_SERVER
macro. For example:
// create an instance of OraOLEDB data source object and // obtain the IDBInitialize interface hr = CoCreateInstance(CLSID_OraOLEDB, NULL, CLSCTX_INPROC_SERVER, IID_IDBInitialize, (void**)&pIDBInitialize);
After the successful creation of an instance of a data source object, the consumer application can initialize the data source and create sessions.
OraOLEDB supports connections to Oracle databases release 7.3.4 and higher. To connect to a specific database, the consumer is required to set the following properties of the DBPROPSET_DBINIT
property set:
DBPROP_AUTH_USERNAME
with the user ID, such as scott
DBPROP_AUTH_PASSWORD
with the password, such as tiger
DBPROP_INIT_DATASOURCE
with the net service name, such as myOraDb
The consumer could also populate DBPROP_INIT_PROMPT
with DBPROMPT_PROMPT
which causes the provider to display a logon box for the user to enter the connect information.
Using DBPROMPT_NOPROMPT
disables display of the logon box. In this case, incomplete logon information causes the provider to return a logon error. However, if this property is set to DBPROMPT_COMPLETE
or DBPROMPT_COMPLETEREQUIRED
, the logon box will only be displayed if the logon information is incomplete.
To connect to an Oracle database using OraOLEDB, the OLE DB connection string must be as follows:
"Provider=OraOLEDB.Oracle;User ID=user;Password=pwd;Data Source=constr;"
When connecting to a remote database, Data
Source
must be set to the appropriate net service name which is the alias in the tnsnames.ora
file. For more information, refer to Oracle9i Net Services Administrator's Guide.
OraOLEDB offers provider-specific Connection String attributes, which are set in the same way as the Provider and User ID are set. The provider-specific connection string attributes are:
CacheType
- specifies the type of cache used to store the rowset data on the client. See "OraOLEDB-specific Connection String Attributes for Rowsets".ChunkSize
- specifies the size of LONG
or LONG RAW
column data stored in the provider's cache. See "OraOLEDB-specific Connection String Attributes for Rowsets".DistribTX
- enables or disables distributed transaction enlistment capability. See "Distributed Transactions".FetchSize
- specifies the size of the fetch array in rows. See "OraOLEDB-specific Connection String Attributes for Rowsets".OSAuthent
- specifies whether OS Authentication will be used when connecting to an Oracle database. See "OS Authentication".PLSQLRSet
- enables or disables the return of a rowset from PL/SQL stored procedures. See "OraOLEDB Custom Properties for Commands".PwdChgDlg
- enables or disables displaying the password change dialog box when the password expires. See "Password Expiration".OLEDB.NET
- enables or disables compatibility with OLE DB .NET Data Provider. See "OLE DB .NET Data Provider Compatibility".The default values for these attributes are located under the \\HKEY_LOCAL_MACHINE\SOFTWARE\ORACLE\OLEDB
registry key.
The registry default values are read by OraOLEDB from the registry when the provider is loaded into memory. If Oracle-specific connection string attributes are not provided at connection time, the default registry values are used. However, if the attributes are provided, these new values override the default registry values.
These attributes can be set by setting the DBPROP_INIT_PROVIDERSTRING
property, provided in the DBPROPSET_DBINIT
property set. For example:
"FetchSize=100;CacheType=Memory;OSAuthent=0;PLSQLRSet=1;"
The DistribTX
attribute specifies whether sessions are enabled to enlist in distributed transactions. Valid values are 0
(disabled) and 1
(enabled). The default is 1
which indicates that sessions are enabled for distributed transaction enlistments.
Applications using Microsoft Transaction Server must have DistribTX
set to 1
, the default.
The OSAuthent
attribute specifies whether OS authentication will be used when connecting to an Oracle database. Valid values are 0
(disabled) and 1
(enabled). The default is 0
which indicates that OS authentication is not used.
OS authentication is the feature by which Oracle uses the security mechanisms of the operating system to authorize users. For more information on this subject and how to set it up on Windows NT clients, refer to the information on authenticating database users on Windows NT in Oracle9i Security and Network Integration Guide.
After the Windows NT client has been set up properly for OS authentication, this feature may be enabled by OraOLEDB clients by setting any of the following:
DBPROP_AUTH_USERNAME
to "/
"DBPROP_INIT_PROVIDERSTRING
to "OSAuthent=1
;"OSAuthent
in the registry to "1
"Oracle9i provides a Password Expiration feature which allows database administrators to force users to change their passwords regularly. The PwdChgDlg
attribute enables or disables the displaying of the password change dialog, whenever a logon fails due to an expired password. When enabled, the provider displays the dialog to change the password. When disabled, the logon fails with an error message. The valid values are 0
(disabled) and 1
(enabled). The default is 1
(enabled). For more information on the Password Expiration feature, see Oracle9i Database Administrator's Guide.
The following are examples illustrating how to connect to an Oracle database using OraOLEDB and ADO.
Note: If the Data Source, User ID, and Password are provided with the Open method, ADO ignores those |
Dim con As New ADODB.Connection con.ConnectionString = "Provider=OraOLEDB.Oracle;Data Source=MyOraDb;" & _ "User ID=scott;Password=tiger;" con.Open
Dim con As New ADODB.Connection con.Provider = "OraOLEDB.Oracle" con.Open "MyOraDb", "scott", "tiger"
Dim con As New ADODB.Connection con.Provider = "OraOLEDB.Oracle" con.ConnectionString = "FetchSize=200;CacheType=Memory;" & _ "OSAuthent=0;PLSQLRSet=1;Data Source=MyOraDb;" & _ "User ID=scott;Password=tiger;" con.Open
Dim con As New ADODB.Connection con.Provider = "OraOLEDB.Oracle" con.Open "MyOraDb", "/", ""
Dim con As New ADODB.Connection con.Provider = "OraOLEDB.Oracle" con.ConnectionString = "Data Source=MyOraDb;OSAuthent=1;" con.Open
An OraOLEDB session object represents a single connection to an Oracle database. The session object exposes the interfaces that allow data access and manipulation.
The first session created on the initialized data source inherits the initial connection established by IDBInitialize::Initialize()
. Subsequent sessions that are created establish their own independent connections to the particular Oracle server specified by the data source properties.
Each session object also defines a transaction space for a data source. All command and rowset objects created from a particular session object are part of the transaction of that session.
After all references to the session object are released, the session object is removed from memory and the connection is dropped.
OraOLEDB supports local and distributed transactions which provide explicit commit and abort.
OraOLEDB does not support nested transactions. In addition, a local transaction cannot be started if the session is currently enlisted in a distributed transaction. This also applies to distributed transactions if the session is currently enlisted in a local transaction.
OraOLEDB supports the ITransactionLocal
interface for explicit transactions. By default, OraOLEDB is in an autocommit mode, meaning that each unit of work done on the database is automatically or implicitly committed. With the use of ITransactionLocal
interface, consumers may explicitly start a transaction for a particular session, allowing a unit of work to be explicitly committed or aborted by the consumer.
OraOLEDB supports the Read Committed (Cursor Stability) isolation level. In this level, the changes made by other transactions are not visible until those transactions are committed.
OraOLEDB consumers must install Oracle Services for Microsoft Transaction Server (MTS) release 9.0.1 or later to be able to participate in Microsoft Transaction Server (or COM+) transactions or to enlist in a distributed transaction coordinated by Microsoft Distributed Transaction Coordinator (MS DTC). For setup and configuration information on Oracle Services for MTS, see Oracle Services for Microsoft Transaction Server Developer's Guide.
OraOLEDB ignores IsoLevel
, IsoFlags
, and pOtherOptions
parameters when ITransactionJoin::JoinTransaction()
is called. These options must be provided when the consumer acquires a transaction object from MS DTC with the ITransactionDispenser::BeginTransaction()
method call.
However, if IsoFlags
is nonzero, XACT_E_NOISORETAIN
is returned.
OraOLEDB supports ANSI SQL as supported by Oracle and the ODBC SQL syntax.
When executing an Oracle PL/SQL stored procedure using a command, use Oracle native syntax or the ODBC procedure call escape sequence in the command text:
BEGIN credit_account(123, 40); END;
CALL credit_account(123, 40)}
OraOLEDB validates and fetches the metadata only for SELECT SQL statements.
When using Oracle ANSI SQL, parameters in the command text are preceded by a colon. In ODBC SQL, parameters are indicated by a question mark ("?
").
OraOLEDB supports input, output, and input/output parameters for PL/SQL stored procedures and stored functions. OraOLEDB supports input parameters for SQL statements.
OraOLEDB custom properties for Commands are grouped under the custom property set ORAPROPSET_COMMANDS
. It provides these properties:
For Visual Basic Users | For C++ Users |
---|---|
|
|
|
|
|
|
This property is similar to the PLSQLRSet
Connection string attribute.
The property specifies whether OraOLEDB must return a rowset from the PL/SQL stored procedure. If the stored procedure, provided by the consumer, returns a rowset, PLSQLRSet
must be set to TRUE
(enabled). This property should be set to FALSE
after the command has been executed. By default, the property is set to FALSE
(disabled).
Consumers should use the property over the attribute, as the property can be set at the command object rather than at the session. By setting it at the command object, the consumer is able to set the property only for the command object executing stored procedures which are returning rowsets. With the attribute, the consumer needed to set it even if only one of many stored procedures being executed by the ADO application returned a rowset. The use of this property should provide a performance boost to applications making use of the attribute previously.
Dim objRes As NEW ADODB.Recordset Dim objCon As NEW ADODB.Connection Dim objCmd As NEW ADODB.Command .... objCmd.ActiveConnection = objCon objCmd.CommandType = adCmdText ' Enabling the PLSQLRSet property indicates to the provider ' that the command returns one or more rowsets objCmd.Properties("PLSQLRSet") = TRUE ' Assume Employees.GetEmpRecords() has a REF CURSOR as ' one of the arguments objCmd.CommandText = "{ CALL Employees.GetEmpRecords(?,?) }" ' Execute the SQL set objRes = objCmd.Execute ' It is a good idea to disable the property after execute as the ' same command object may be used for a different SQL statement objCmd.Properties("PLSQLRSet") = FALSE
This property allows the consumers to specify whether any of the parameters bound to the command are of Oracle's N datatypes (NCHAR
, NVARCHAR
or NCLOB
). This information is required by OraOLEDB to detect and bind the parameters appropriately. This property should not be set for commands executing SELECT
statements. However, this property must be set for all other SQLs such as INSERT
, UPDATE
, and DELETE
.
The use of this property should be limited to SQLs containing parameters of N datatype as setting it incurs a processing overhead of at least one round-trip to the database. By default, this property is set to FALSE
.
Note: Consumers are required to use the ODBC procedure call escape sequence to call stored procedures or functions having N datatype parameters. |
Dim objCon As NEW ADODB.Connection Dim objCmd As NEW ADODB.Command Dim prEmpno As NEW ADODB.Parameter Dim prEname As NEW ADODB.Parameter ... objCmd.ActiveConnection = objCon objCmd.CommandType = adCmdText ' Create and append the parameters to the command object Set prEmpno = objCmd.CreateParameter("prEmpno", adSmallInt, adParamInput, ,8521) ' prEname is bound to a NVARCHAR column in the EMP table Set prEname = objCmd.CreateParameter("prEname", adBSTR, adParamInput, , "Joe") objCmd.Parameters.Append prEmpno objCmd.Parameters.Append prEname ' Enabling the NDatatype property indicates to the provider ' that one or more of the bound parameters is of N datatype objCmd.Properties("NDatatype") = TRUE ' Assume column ENAME in table EMP is of NVARCHAR type objCmd.CommandText = "INSERT INTO EMP (EMPNO, ENAME) VALUES (?, ?)" ' Execute the SQL objCmd.Execute ' It is a good idea to disable the property after execute as the same command
' object may be used for a different SQL statement objCmd.Properties("NDatatype") = FALSE
This property allows the consumer to specify whether one or more of the parameters bound to the stored procedures are of Oracle's LOB datatype (CLOB
, BLOB
, or NCLOB
). OraOLEDB requires this property to be set to TRUE
, in order to fetch the parameter list of the stored procedure prior to execution. The use of this property limits the processing overhead to stored procedures having one or more LOB datatype parameters. This property should be set to FALSE
after the command has been executed. By default, the property is set to FALSE
.
Note: Consumers are required to use the ODBC procedure call escape sequence to call stored procedures or functions having LOB datatype parameters. |
Dim objCon As NEW ADODB.Connection Dim objCmd As NEW ADODB.Command Dim prCLOB As NEW ADODB.Parameter ... objCmd.ActiveConnection = objCon objCmd.CommandType = adCmdText ' Create and append the parameters to the command object Set prCLOB = objCmd.CreateParameter("prCLOB", adLongVarchar, adParamOutput, _
10000) objCmd.Parameters.Append prCLOB ' Enabling the SPPrmsLOB property indicates to the provider ' that one or more of the bound parameters is of LOB datatype objCmd.Properties("SPPrmsLOB") = TRUE ' Assume the Stored Procedure requires a CLOB parameter objCmd.CommandText = "{ call storedproc(?) }" 'Execute the SQL objCmd.Execute ' It is a good idea to disable the property after execute as the ' same command object may be used for a different SQL statement objCmd.Properties("SPPrmsLOB") = FALSE
Oracle Provider for OLE DB allows consumers to execute a PL/SQL stored procedure with an argument of REF
CURSOR
type or a stored function returning a REF
CURSOR
.
OraOLEDB returns a rowset for the REF
CURSOR
bind variable. Because there is no predefined datatype for REF
CURSOR
in the OLE DB specification, the consumer must not bind this parameter.
If the PL/SQL stored procedure has one or more arguments of REF
CURSOR
type, OraOLEDB binds these arguments appropriately and returns a rowset for each argument of REF
CURSOR
type.
If the PL/SQL stored function returns a REF
CURSOR
or has an argument of REF
CURSOR
type, OraOLEDB binds these appropriately and returns a rowset for each REF
CURSOR
type.
To use this feature, stored procedures or functions must be called in the ODBC procedure call escape sequence.
The stored procedure or function being called could be either standalone or packaged. However, the REF
CURSOR
being returned must be explicitly defined in a package in the database.
OraOLEDB supports returning more than one rowset from a stored procedure. Consumers can use this feature to access all the REF
CURSOR
s being returned by a stored procedure.
CREATE OR REPLACE PACKAGE Employees AS TYPE empcur IS REF CURSOR; PROCEDURE GetEmpRecords(p_cursor OUT empcur, q_cursor OUT empcur, indeptno IN NUMBER, p_errorcode OUT NUMBER); FUNCTION GetDept(inempno IN NUMBER, p_errorcode OUT NUMBER) RETURN empcur; END Employees; CREATE OR REPLACE PACKAGE BODY Employees AS PROCEDURE GetEmpRecords(p_cursor OUT empcur, q_cursor OUT empcur, indeptno IN NUMBER, p_errorcode OUT NUMBER) IS BEGIN p_errorcode := 0; OPEN p_cursor FOR SELECT * FROM emp WHERE deptno = indeptno ORDER BY empno; OPEN q_cursor FOR SELECT empno FROM emp WHERE deptno = indeptno ORDER BY empno; EXCEPTION WHEN OTHERS THEN p_errorcode:= SQLCODE; END GetEmpRecords; FUNCTION GetDept(inempno IN NUMBER, p_errorcode OUT NUMBER) RETURN empcur IS p_cursor empcur; BEGIN p_errorcode := 0; OPEN p_cursor FOR SELECT deptno FROM emp WHERE empno = inempno; RETURN (p_cursor); EXCEPTION WHEN OTHERS THEN p_errorcode:= SQLCODE; END GetDept; END Employees;
Dim Con As New ADODB.Connection Dim Rst1 As New ADODB.Recordset Dim Rst2 As New ADODB.Recordset Dim Rst3 As New ADODB.Recordset Dim Cmd As New ADODB.Command Dim Prm1 As New ADODB.Parameter Dim Prm2 As New ADODB.Parameter Con.Provider = "OraOLEDB.Oracle" Con.ConnectionString = "Data Source=MyOraDb;" & _ "User ID=scott;Password=tiger;" Con.Open Cmd.ActiveConnection = Con ' Although Employees.GetEmpRecords() takes four parameters, only ' two need to be bound because Ref cursor parameters are automatically ' bound by the provider. Set Prm1 = Cmd.CreateParameter("Prm1", adSmallInt, adParamInput, , 30) Cmd.Parameters.Append Prm1 Set Prm2 = Cmd.CreateParameter("Prm2", adSmallInt, adParamOutput) Cmd.Parameters.Append Prm2 ' Enable PLSQLRSet property Cmd.Properties ("PLSQLRSet") = TRUE ' Stored Procedures returning resultsets must be called using the ' ODBC escape sequence for calling stored procedures. Cmd.CommandText = "{CALL Employees.GetEmpRecords(?, ?)}" ' Get the first recordset Set Rst1 = Cmd.Execute ' Disable PLSQLRSet property Cmd.Properties("PLSQLRSet") = FALSE ' Get the second recordset Set Rst2 = Rst1.NextRecordset ' Just as in a stored procedure, the REF CURSOR return value must ' not be bound in a stored function. Prm1.Value = 7839 Prm2.Value = 0 ' Enable PLSQLRSet property Cmd.Properties("PLSQLRSet") = TRUE ' Stored Functions returning resultsets must be called using the ' ODBC escape sequence for calling stored functions. Cmd.CommandText = "{CALL Employees.GetDept(?, ?)}" ' Get the rowset Set Rst3 = Cmd.Execute ' Disable PLSQLRSet Cmd.Properties ("PLSQLRSet") = FALSE ' Clean up Rst1.Close Rst2.Close Rst3.Close
OraOLEDB supports IOpenRowset::OpenRowset
and ICommand::Execute
for creating rowsets.
When using IOpenRowset::OpenRowset
, note the following guidelines:
pTableID
parameter must contain a DBID
structure that specifies a base table or a view.DBID
structure's eKind
member must be set to DBKIND_GUID_NAME
, DBKIND_NAME
, or DBKIND_PGUID_NAME
.DBID
structure's uName
member must specify the base table or view name as a Unicode character string. It cannot be NULL
.pIndexID
parameter of OpenRowset must be NULL
.OraOLEDB supports SQL SELECT
statements that return rowsets. OraOLEDB also supports returning rowsets from PL/SQL stored procedures and functions.
By default, ADO creates a non-updatable rowset from a command object. An updatable rowset can be created by setting the Updatability
and IRowsetChange
properties on the command object. The Updatability
property can be set to the following values:
Value | Description |
---|---|
|
update |
|
delete |
|
update and delete |
|
insert |
|
insert and update |
|
insert and delete |
|
insert, delete, and update |
The following ADO code sample sets the Updatability
property on a command object to allow insert, delete, and update operations on the rowset object.
Dim Cmd As New ADODB.Command Dim Rst As New ADODB.Recordset Dim Con As New ADODB.Connection ... Cmd.ActiveConnection = Con Cmd.CommandText = "SELECT * FROM emp" Cmd.CommandType = adCmdText cmd.Properties("IRowsetChange") = TRUE Cmd.Properties("Updatability") = 7 ' creates an updatable rowset Set Rst = cmd.Execute
OraOLEDB supports both immediate and deferred update mode. However, insert and update operations cannot be deferred when the operation changes a non-scalar column, such as LONG
, BLOB
, or CLOB
. When non-scalar column values are changed in a deferred update mode, the entire row is transmitted to the database as though the operation was in an immediate update mode. In addition, these operations cannot be undone with the Undo
method (ADO) or IRowsetUpdate::Undo()
. But if they are in a transaction, they can be rolled back with RollbackTrans method (ADO) or ITransactionLocal::Abort()
.
Rowsets created using queries with joins are updatable by OraOLEDB only with the Client Cursor Engine enabled. C/C++ OLE DB consumers must enable this service to make these rowsets updatable. ADO consumers must specify the CursorLocation
as adUseClient
to make these rowsets updatable.
For example:
Dim objCon As New ADODB.Connection Dim objRst As New ADODB.Recordset objCon.Provider = "OraOLEDB.Oracle" objCon.Open "MyOraDb", "scott", "tiger" objRst.CursorLocation = adUseClient 'ADO Client Cursor objRst.Open "select ename, dname " & _ "from emp, dept " & _ "where emp.deptno = dept.deptno", _ objCon, adOpenStatic, adLockOptimistic, adCmdText 'Recordset created is updatable. Please note that CursorLocation 'needs to be explicitly set to adUseClient for this join recordset 'to be updatable.
If DBPROP_SERVERDATAONINSERT
(Server Data on Insert) is set to TRUE
using OraOLEDB, the consumer can obtain defaults, sequences, and triggered column values from newly inserted and updated rows, if the insert and update operations are made through the rowset.
Having DBPROP_SERVERDATAONINSERT
set to TRUE
may degrade performance for both insert and update executions using a rowset because OraOLEDB fetches row data from the database for the newly inserted and updated row. However, if DBPROP_SERVERDATAONINSERT
is set to its default value of FALSE
, only the explicitly provided values for insert and update operations get returned when column values are requested for those rows.
If the base table from which the rowset was created does not contain any defaults, sequences, or triggers, it is highly recommended that DBPROP_SERVERDATAONINSERT
retain its default value of FALSE
.
The DBPROP_SERVERDATAONINSERT
property does not affect the performance of insert and update executions using the command object.
OraOLEDB only supports searches performed on CHAR
, DATE
, FLOAT
, NUMBER
, RAW
, and VARCHAR2
columns. Otherwise, DB_E_NOTSUPPORTED
is returned.
When a search is done with a NULL
value, only the DBCOMPAREOPS_EQ
and DBCOMPAREOPS_NE
compare operations are supported. Otherwise, DB_E_NOTSUPPORTED
is returned.
OraOLEDB-specific connection string attributes which affect the performance of the rowset are:
CacheType
- specifies the type of caching used by the provider to store rowset data. OraOLEDB provides two caching mechanisms:ChunkSize
- This attribute specifies the size, in bytes, of the data in LONG
and LONG RAW
columns fetched and stored in the provider cache. Providing a high value for this attribute improves performance, but requires more memory to store the data in the rowset. Valid values are 1
to 65535
. The default is 100
.FetchSize
- specifies the number of rows the provider will fetch at a time (fetch array). It must be set appropriately depending on the data size and the response time of the network. If the value is set too high, this could result in more wait time during the execution of the query. If the value is set too low, this could result in many more round trips to the database. Valid values are 1
to 429,496,296
. The default is 100
.The default attributes values are set in the registry. For more information, see "Default Attribute Values". The following ADO code example overrides the default attribute values:
Dim con As ADODB.Connection Set con = NEW ADODB.Connection con.ConnectionString = "Provider=OraOLEDB.Oracle;User ID=scott;" & _ "Password=tiger;Data Source=MyOraDB;" & _ "FetchSize=200;CacheType=File;" con.Open
Setting the ADO Rowset property LockType
to adLockPessimistic
is not supported by Oracle Provider for OLE DB. If LockType
is set to adLockPessimistic
, OraOLEDB behaves similar to when set as adLockOptimistic
. This behavior occurs because OraOLEDB does not perform explicit locks on the rows being modified. However, when the new data is submitted to the database, it only performs the update if the rowset data was not already updated by another user, which means that dirty writes are not allowed. LockType values adLockReadOnly
, adLockBatchOptimistic
, and adLockOptimistic
are supported by OraOLEDB.
Setting ADO Rowset property CursorType
to adOpenKeyset
or adOpenDynamic
is not supported by Oracle Provider for OLE DB. OraOLEDB does not support either of the two as Oracle supports Statement Level Read Consistency, which ensures that the data returned by a query contains only committed data as of the time the query was executed. CursorType
values adOpenStatic
and adOpenForwardOnly
are supported by OraOLEDB.
The schema rowsets available through Oracle Provider for OLE DB are:
DBSCHEMA_COLUMNS
DBSCHEMA_INDEXES
DBSCHEMA_SCHEMATA
DBSCHEMA_VIEWS
DBSCHEMA_TABLES
DBSCHEMA_PROVIDER_TYPES
(forward scroll only)DBSCHEMA_FOREIGN_KEYS
DBSCHEMA_PRIMARY_KEYS
DBSCHEMA_PROCEDURES
DBSCHEMA_PROCEDURE_PARAMETERS
The date format for the Oracle session cannot be set using ALTER SESSION SET NLS_DATE_FORMAT
command. In Visual Basic, the date formats are controlled by the Regional Settings properties in the Windows Control Panel. For more information on Visual Basic date formats, refer to your Visual Basic documentation.
For Oracle Provider for OLE DB, NLS_DATE_FORMAT
is fixed for the session to 'YYYY-MM-DD HH24:MI:SS
' by the provider. If you pass the date to Oracle as a string, the date must be in the 'YYYY-MM-DD HH24:MI:SS
' format. For example:
SELECT * FROM EMP WHERE HIREDATE > '1981-06-15 17:32:12'
To use a different format, you need to use the SQL function, TO_DATE()
, to specify the format for dates passed as strings. For example:
SELECT * FROM EMP WHERE HIREDATE > TO_DATE('15-JUN-81', 'DD-MON-YY')
However, for dates passed as parameters, the date format is controlled by ADO, which is controlled by the Regional Settings in the Windows Control Panel. In this case, TO_DATE()
should not be used. For example:
Private Sub Command1_Click() Dim objCon As New ADODB.Connection Dim objCmd As New ADODB.Command Dim objRst As New ADODB.Recordset Dim pDate As New ADODB.Parameter objCon.Provider = "OraOLEDB.Oracle" objCon.Open "MyOraDb", "scott", "tiger" Set pDate = objCmd.CreateParameter("pDate", adDate, adParamInput) objCmd.Parameters.Append pDate objCmd.CommandText = _ "SELECT * FROM EMP WHERE HIREDATE > ?" objCmd.ActiveConnection = objCon objCmd.CommandType = adCmdText pDate.Value = "06/15/1981" Set objRst = objCmd.Execute ... End Sub
The names of all objects (tables, columns, views, and so forth) in Oracle are case-sensitive. This allows the two objects EMP
and emp
to exist in the same namespace in the database.
The query, SELECT ename FROM emp
, executes correctly even though the table name is EMP
(all uppercase) in the database. However, if you want to specify object names in mixed case, you can do so by enclosing the name in double quotes. For example:
SELECT ename FROM "Emp"
will execute successfully if the table name in the database is Emp
. Double quotes preserve the case of the object names in Oracle.
The ISequentialStream
interface is supported for all LONG
, LONG RAW
, and LOB (BLOB
, CLOB
, NCLOB
, and BFILE
) columns. The consumer can use this interface to read and write to all the LOB columns, except BFILE
which is read-only. To have read and write access to these columns, the SELECT
SQL statement used to create the rowset should not contain a join.
Note: Although most of the LOB columns in an Oracle database support up to 4 GB of data storage, ADO limits the maximum column size to 2 GB. |
Columns having the BFILE
datatype are not updatable in the Rowset
interface. However, these columns can be updated using the Command interface, if the update is limited to modifying the directory and name of the external file pointed to by the BFILE
column. For example:
INSERT INTO topomaps (areanum, topomap) VALUES (158, BFILENAME('mapdir', 'topo158.tps'))
For more information on LOBs, see Oracle9i Application Developer's Guide - Large Objects (LOBs).
OraOLEDB supports the Unicode character set. Using this feature, consumers can use OraOLEDB to access data in multiple languages on the same client computer. It can be especially useful in creating global Internet applications supporting as many languages as the Unicode standard entails. For example, you can write a single Active Server Page (ASP) that accesses an Oracle9i database to dynamically generate contents in Japanese, Arabic, English, and Thai.
The Oracle databases store the Unicode data in the UTF8 encoding scheme, which is an ASCII compatible multibyte encoding of Unicode. Microsoft Windows 2000 and NT 4.0 use the UCS2 encoding, which is a 2-byte fixed width encoding scheme. OraOLEDB transparently converts the data between the two encoding schemes allowing the consumers to deal with only UCS2.
Note: The Unicode support is transparent to ADO consumers. OLE DB consumers using C/C++ need to explicitly specify |
OraOLEDB works in two modes, Unicode mode and non-Unicode mode. When the client character set is not a superset of the server character set, OraOLEDB automatically enables the Unicode mode. In this mode, OraOLEDB stores the data in its cache in the UCS2 encoding scheme. The user should ensure that the database's character set is UTF8 in order to prevent any data loss.
If the client character set is a superset of the server's, the provider operates in the non-Unicode mode. This mode provides slightly better performance as it does not have to deal with larger character buffers required by the UCS2 encoding.
The detection of the client's and the server's character set is performed during logon.
Note: OraOLEDB no longer requires the client character set to be set to UTF8 to enable the Unicode mode. The provider still supports such setups but no longer requires it. |
See "Datatype Mappings in Rowsets and Parameters" for further information.
In order to prevent any data loss, the database character set should be UTF8. Other than this, there is no other setup required for the Unicode support.
You must ensure that the Oracle database is configured to store the data in the UTF8 character set. The character set configuration is typically specified during database creation. To check the character set setting of your database, execute the following query in SQL*Plus:
SQL> SELECT parameter, value FROM nls_database_parameters WHERE parameter = 'NLS_CHARACTERSET';
If the character set of your database is not UTF8, you need to create a new database with the UTF8 character set and import your data into it. See Oracle9i Database Administrator's Guide for more information.
See Also:
Oracle9i Database Globalization Support Guide for general information |
OLE and COM objects report errors through the HRESULT
return code of the object member functions. An OLE/COM HRESULT
is a bit-packed structure. OLE provides macros that dereference structure members. OraOLEDB exposes IErrorLookup
to retrieve information about an error.
All objects support extended error information. For this, the consumer must instantiate the OLE DB Extended Error object followed by calling the method GetErrorDescription()
to get the error text.
// Instantiate OraOLEDBErrorLookup and obtain a pointer to its // IErrorLookup interface CoCreateInstance(CLSID_OraOLEDBErrorLookup, NULL, CLSCTX_INPROC_SERVER, IID_IErrorLookup, (void **)&pIErrorLookup) //Call the method GetErrorDescription() to get the full error text pIErrorLookup->GetErrorDescription()
The OraOLEDB provider returns the entire error stack in one text block.
For ADO users, the following example applies:
Dim oerr As ADODB.Error For Each oerr in con.Errors MsgBox "Error: " & oerr.Description & vbCrLf _ & "Source: " & oerr.Source Next
The OLE DB .NET Data Provider can utilize OraOLEDB as the OLE DB Provider for accessing Oracle.
To make OraOLEDB compatible with OLE DB .NET Data Provider, set the connection string attribute OLEDB.NET
to True
.
Setting the OLEDB.NET
attribute to False
disables .NET compatibility.
When using OraOLEDB with the OLE DB .NET Data Provider, the OLEDB.NET
connection attribute must be set to True
as shown in the following examples:
// in VB.NET Dim con As New OleDbConnection() con.ConnectionString = "Provider=OraOLEDB.Oracle;User Id=scott;" & _ "Password=tiger;Data Source=Oracle;OLEDB.NET=True;" con.Open // in C# ... OleDbConnection con = new OleDbConnection(); con.ConnectionString = "Provider=OraOLEDB.Oracle;User Id=scott;" + "Password=tiger;Data Source=Oracle;OLEDB.NET=true;" con.Open(); ...
ADO allows OraOLEDB provider-specific properties to be set at the object level. The OraOLEDB-specific properties SPPrmsLOB
and NDatatype
can only be set at the ADO command object level, as shown in the following example:
// in VB Dim cmd as new ADODB.Command ... cmd.Properties("SPPrmsLOB") = True cmd.Properties("NDatatype") = True ...
However, the OLE DB .NET Data Provider cannot expose OLE DB provider-specific properties at the object level. Therefore, the SPPrmsLOB
and NDatatype
properties can only be set as connection string attributes when OraOLEDB is used by OLE DB .NET Data Provider:
// in VB.NET Dim con As New OleDbConnection() con.ConnectionString = "Provider=OraOLEDB.Oracle;User Id=scott;" & _ "Password=tiger;Data Source=Oracle;OLEDB.NET=True;" & _ "SPPrmsLOB=False;NDatatype=False;" con.Open()
Both SPPrmsLOB
and NDatatype
connection string attributes are set to False
by default if they are not specified.
Setting either of these connection string attributes to True
incurs additional processing overhead when executing commands with parameters. For this reason, before setting either attribute to True,
see "OraOLEDB Custom Properties for Commands".
In order for the OleDbDataAdapter.Update()
method to properly update Oracle with changes made in the DataTable
, the DataTable
must contain a primary key of a database table. If the database table does not contain a primary key, the ROWID
must be selected explicitly when populating the DataTable
, so that the ROWID
can be used to uniquely identify a row when updating a row in the database.
Do not select the ROWID
from database tables that contains a primary key. If the ROWID
is selected along with a primary key, the ROWID
will be the only column marked as the primary key.
The following simple example illustrates how to use Oracle Provider for OLE DB with ADO in Visual Basic 6.0 to connect to an Oracle database and execute PL/SQL stored procedures and functions.
This example assumes that the Oracle database has the demonstration table EMP
under the user account scott
. The scott
account is included in the Oracle starter database. If the account does not exist on your database, create the account before running the sample program. If your database does not contain the emp
table, you can use the demobld.sql
script to create the demonstration tables.
This example also uses exampledb
as the database network alias when connecting to the Oracle database. You will need to change this network alias to match your system.
scott
with the password tiger
.demobld.sql
script:
SQL> @ORACLE_BASE\ORACLE_HOME
\sqlplus\demo\demobld.sql;
After the emp
table has been created in the scott
account, you need to create the PL/SQL package that contains the stored procedure and function that are run in the Visual Basic example.
scott
with the password tiger
.After the Oracle database setups are completed, you can create the Visual Basic 6.0 project.
GetEmpRecords
. The other will run the code to execute the PL/SQL function GetDept
.
GetEmpRecords
.Dim Oracon As ADODB.Connection Dim recset As New ADODB.Recordset Dim cmd As New ADODB.Command Dim param1 As New ADODB.Parameter Dim param2 As New ADODB.Parameter Dim objErr As ADODB.Error Dim Message, Title, Default, EmpNoValue Message = "Enter an employee number (5000 - 9000)" Title = "Choose an Employee" Default = "7654" On Error GoTo err_test EmpNoValue = InputBox(Message, Title, Default) If EmpNoValue = "" Then Exit Sub If EmpNoValue < 5000 Or EmpNoValue > 9000 Then EmpNoValue = 7654 Set Oracon = CreateObject("ADODB.Connection") Oracon.ConnectionString = "Provider=OraOLEDB.Oracle;" & _ "Data Source=exampledb;" & _ "User ID=scott;" & _ "Password=tiger;" Oracon.Open Set cmd.ActiveConnection = Oracon Set param1 = cmd.CreateParameter("param1", adSmallInt, adParamInput, , EmpNoValue) cmd.Parameters.Append param1 Set param2 = cmd.CreateParameter("param2", adSmallInt, adParamOutput) cmd.Parameters.Append param2 ' Enable PLSQLRSet property Cmd.Properties ("PLSQLRSet") = TRUE cmd.CommandText = "{CALL Employees.GetDept(?, ?)}" Set recset = cmd.Execute ' Disable PLSQLRSet property Cmd.Properties ("PLSQLRSet") = FALSE MsgBox "Number: " & EmpNoValue & " Dept: " & recset.Fields("deptno").Value Exit Sub err_test: MsgBox Error$ For Each objErr In Oracon.Errors MsgBox objErr.Description Next Oracon.Errors.Clear Resume Next
GetDept
.Dim Oracon As ADODB.Connection Dim recset As New ADODB.Recordset Dim cmd As New ADODB.Command Dim param1 As New ADODB.Parameter Dim param2 As New ADODB.Parameter Dim objErr As ADODB.Error Dim Message, Title, Default, DeptValue Message = "Enter a department number (10, 20, or 30)" Title = "Choose a Department" Default = "30" On Error GoTo err_test DeptValue = InputBox(Message, Title, Default) If DeptValue = "" Then Exit Sub If DeptValue < 10 Or DeptValue > 30 Then DeptValue = 30 Set Oracon = CreateObject("ADODB.Connection") Oracon.ConnectionString = "Provider=OraOLEDB.Oracle;" & _ "Data Source=exampledb;" & _ "User ID=scott;" & _ "Password=tiger;" Oracon.Open Set cmd = New ADODB.Command Set cmd.ActiveConnection = Oracon Set param1 = cmd.CreateParameter("param1", adSmallInt, adParamInput, , DeptValue) cmd.Parameters.Append param1 Set param2 = cmd.CreateParameter("param2", adSmallInt, adParamOutput) cmd.Parameters.Append param2 ' Enable PLSQLRSet property Cmd.Properties ("PLSQLRSet") = TRUE cmd.CommandText = "{CALL Employees.GetEmpRecords(?, ?)}" Set recset = cmd.Execute ' Disable PLSQLRSet property Cmd.Properties ("PLSQLRSet") = FALSE Do While Not recset.EOF MsgBox "Number: " & recset.Fields("empno").Value & " Name: " & recset.Fields("ename").Value & " Dept: " & recset.Fields("deptno").Value recset.MoveNext Loop Exit Sub err_test: MsgBox Error$ For Each objErr In Oracon.Errors MsgBox objErr.Description Next Oracon.Errors.Clear Resume Next
Text description of the illustration oledbvb2.gif
Once you have entered a department number and OK, another dialog box displays employee names and numbers from that department.
|
Copyright © 1999, 2002 Oracle Corporation. All Rights Reserved. |
|