Oracle® Database Globalization Support Guide 10g Release 1 (10.1) Part Number B10749-02 |
|
|
View PDF |
This chapter describes how to use Oracle's database access products with Unicode. It contains the following topics:
Oracle offers several database access products for inserting and retrieving Unicode data. Oracle offers database access products for commonly used programming environments such as Java and C/C++. Data is transparently converted between the database and client programs, which ensures that client programs are independent of the database character set and national character set. In addition, client programs are sometimes even independent of the character datatype, such as NCHAR
or CHAR
, used in the database.
To avoid overloading the database server with data conversion operations, Oracle always tries to move them to the client side database access products. In a few cases, data must be converted in the database, which affects performance. This chapter discusses details of the data conversion paths.
Oracle Corporation offers a comprehensive set of database access products that allow programs from different development environments to access Unicode data stored in the database. These products are listed in Table 7-1.
Table 7-1 Oracle Database Access Products
Programming Environment | Oracle Database Access Products |
---|---|
C/C++ | Oracle Call Interface (OCI) Oracle Pro*C/C++ Oracle ODBC driver Oracle Provider for OLE DB Oracle Data Provider for .NET |
Java | Oracle JDBC OCI or thin driver Oracle server-side thin driver Oracle server-side internal driver |
PL/SQL | Oracle PL/SQL and SQL |
Visual Basic/C# | Oracle ODBC driver Oracle Provider for OLE DB |
Figure 7-1 shows how the database access products can access the database.
The Oracle Call Interface (OCI) is the lowest level API that the rest of the client-side database access products use. It provides a flexible way for C/C++ programs to access Unicode data stored in SQL CHAR
and NCHAR
datatypes. Using OCI, you can programmatically specify the character set (UTF-8, UTF-16, and others) for the data to be inserted or retrieved. It accesses the database through Oracle Net.
Oracle Pro*C/C++ enables you to embed SQL and PL/SQL in your programs. It uses OCI's Unicode capabilities to provide UTF-16 and UTF-8 data access for SQL CHAR
and NCHAR
datatypes.
The Oracle ODBC driver enables C/C++, Visual Basic, and VBScript programs running on Windows platforms to access Unicode data stored in SQL CHAR
and NCHAR
datatypes of the database. It provides UTF-16 data access by implementing the SQLWCHAR
interface specified in the ODBC standard specification.
The Oracle Provider for OLE DB enables C/C++, Visual Basic, and VBScript programs running on Windows platforms to access Unicode data stored in SQL CHAR
and NCHAR
datatypes. It provides UTF-16 data access through wide string OLE DB datatypes.
The Oracle Data Provider for .NET enables programs running in any .NET programming environment on Windows platforms to access Unicode data stored in SQL CHAR
and NCHAR
datatypes. It provides UTF-16 data access through Unicode datatypes.
Oracle JDBC drivers are the primary Java programmatic interface for accessing an Oracle database. Oracle provides the following JDBC drivers:
The JDBC OCI driver that is used by Java applications and requires the OCI library
The JDBC thin driver, which is a pure Java driver that is primarily used by Java applets and supports the Oracle Net protocol over TCP/IP
The JDBC server-side thin driver, a pure Java driver used inside Java stored procedures to connect to another Oracle server
The JDBC server-side internal driver that is used inside the Oracle server to access the data in the database
All drivers support Unicode data access to SQL CHAR
and NCHAR
datatypes in the database.
The PL/SQL and SQL engines process PL/SQL programs and SQL statements on behalf of client-side programs such as OCI and server-side PL/SQL stored procedures. They allow PL/SQL programs to declare CHAR
, VARCHAR2
, NCHAR
, and NVARCHAR2
variables and to access SQL CHAR
and NCHAR
datatypes in the database.
The following sections describe how each of the database access products supports Unicode data access to an Oracle database and offer examples for using those products:
SQL is the fundamental language with which all programs and users access data in an Oracle database either directly or indirectly. PL/SQL is a procedural language that combines the data manipulating power of SQL with the data processing power of procedural languages. Both SQL and PL/SQL can be embedded in other programming languages. This section describes Unicode-related features in SQL and PL/SQL that you can deploy for multilingual applications.
This section contains the following topics:
There are three SQL NCHAR
datatypes:
When you define a table column or a PL/SQL variable as the NCHAR
datatype, the length is always specified as the number of characters. For example, the following statement creates a column with a maximum length of 30 characters:
CREATE TABLE table1 (column1 NCHAR(30));
The maximum number of bytes for the column is determined as follows:
maximum number of bytes = (maximum number of characters) x (maximum number of bytes for each character)
For example, if the national character set is UTF8, then the maximum byte length is 30 characters times 3 bytes for each character, or 90 bytes.
The national character set, which is used for all NCHAR
datatypes, is defined when the database is created. The national character set can be either UTF8 or AL16UTF16. The default is AL16UTF16.
The maximum column size allowed is 2000 characters when the national character set is UTF8 and 1000 when it is AL16UTF16. The actual data is subject to the maximum byte limit of 2000. The two size constraints must be satisfied at the same time. In PL/SQL, the maximum length of NCHAR
data is 32767 bytes. You can define an NCHAR
variable of up to 32767 characters, but the actual data cannot exceed 32767 bytes. If you insert a value that is shorter than the column length, then Oracle pads the value with blanks to whichever length is smaller: maximum character length or maximum byte length.
Note: UTF8 may affect performance because it is a variable-width character set. Excessive blank padding ofNCHAR fields decreases performance. Consider using the NVARCHAR datatype or changing to the AL16UTF16 character set for the NCHAR datatype. |
The NVARCHAR2
datatype specifies a variable length character string that uses the national character set. When you create a table with an NVARCHAR2
column, you specify the maximum number of characters for the column. Lengths for NVARCHAR2
are always in units of characters, just as for NCHAR
. Oracle subsequently stores each value in the column exactly as you specify it, if the value does not exceed the column's maximum length. Oracle does not pad the string value to the maximum length.
The maximum column size allowed is 4000 characters when the national character set is UTF8 and 2000 when it is AL16UTF16. The maximum length of an NVARCHAR2
column in bytes is 4000. Both the byte limit and the character limit must be met, so the maximum number of characters that is actually allowed in an NVARCHAR2
column is the number of characters that can be written in 4000 bytes.
In PL/SQL, the maximum length for an NVARCHAR2
variable is 32767 bytes. You can define NVARCHAR2
variables up to 32767 characters, but the actual data cannot exceed 32767 bytes.
The following statement creates a table with one NVARCHAR2
column whose maximum length in characters is 2000 and maximum length in bytes is 4000.
CREATE TABLE table2 (column2 NVARCHAR2(2000));
NCLOB
is a character large object containing Unicode characters, with a maximum size of 4 gigabytes. Unlike the BLOB
datatype, the NCLOB
datatype has full transactional support so that changes made through SQL, the DBMS_LOB
package, or OCI participate fully in transactions. Manipulations of NCLOB
value can be committed and rolled back. Note, however, that you cannot save an NCLOB
locator in a PL/SQL or OCI variable in one transaction and then use it in another transaction or session.
NCLOB
values are stored in the database in a format that is compatible with UCS-2, regardless of the national character set. Oracle translates the stored Unicode value to the character set requested on the client or on the server, which can be fixed-width or variable-width. When you insert data into an NCLOB
column using a variable-width character set, Oracle converts the data into a format that is compatible with UCS-2 before storing it in the database.
See Also: Oracle Database Application Developer's Guide - Large Objects for more information about theNCLOB datatype |
Oracle supports implicit conversions between SQL NCHAR
datatypes and other Oracle datatypes, such as CHAR
, VARCHAR2
, NUMBER
, DATE
, ROWID
, and CLOB
. Any implicit conversions for CHAR
and VARCHAR2
datatypes are also supported for SQL NCHAR
datatypes. You can use SQL NCHAR
datatypes the same way as SQL CHAR
datatypes.
Type conversions between SQL CHAR
datatypes and SQL NCHAR
datatypes may involve character set conversion when the database and national character sets are different. Padding with blanks may occur if the target data is either CHAR
or NCHAR
.
See Also: Oracle Database SQL Reference |
Data loss can occur during datatype conversion when character set conversion is necessary. If a character in the source character set is not defined in the target character set, then a replacement character is used in its place. For example, if you try to insert NCHAR
data into a regular CHAR
column and the character data in NCHAR
(Unicode) form cannot be converted to the database character set, then the character is replaced by a replacement character defined by the database character set. The NLS_NCHAR_CONV_EXCP
initialization parameter controls the behavior of data loss during character type conversion. When this parameter is set to TRUE
, any SQL statements that result in data loss return an ORA-12713
error and the corresponding operation is stopped. When this parameter is set to FALSE
, data loss is not reported and the unconvertible characters are replaced with replacement characters. The default value is TRUE
. This parameter works for both implicit and explicit conversion.
In PL/SQL, when data loss occurs during conversion of SQL CHAR
and NCHAR
datatypes, the LOSSY_CHARSET_CONVERSION
exception is raised for both implicit and explicit conversion.
In some cases, conversion between datatypes is possible in only one direction. In other cases, conversion in both directions is possible. Oracle defines a set of rules for conversion between datatypes. Table 7-2 contains the rules for conversion between datatypes.
Table 7-2 Rules for Conversion Between Datatypes
Statement | Rule |
---|---|
INSERT /UPDATE statement |
Values are converted to the datatype of the target database column. |
SELECT INTO statement |
Data from the database is converted to the datatype of the target variable. |
Variable assignments | Values on the right of the equal sign are converted to the datatype of the target variable on the left of the equal sign. |
Parameters in SQL and PL/SQL functions | CHAR , VARCHAR2 , NCHAR , and NVARCHAR2 are loaded the same way. An argument with a CHAR , VARCHAR2 , NCHAR or NVARCHAR2 datatype is compared to a formal parameter of any of the CHAR , VARCHAR2 , NCHAR or NVARCHAR2 datatypes. If the argument and formal parameter datatypes do not match exactly, then implicit conversions are introduced when data is copied into the parameter on function entry and copied out to the argument on function exit. |
Concatenation || operation or CONCAT function |
If one operand is a SQL CHAR or NCHAR datatype and the other operand is a NUMBER or other non-character datatype, then the other datatype is converted to VARCHAR2 or NVARCHAR2 . For concatenation between character datatypes, see "SQL NCHAR datatypes and SQL CHAR datatypes". |
SQL CHAR or NCHAR datatypes and NUMBER datatype |
Character value is converted to NUMBER datatype |
SQL CHAR or NCHAR datatypes and DATE datatype |
Character value is converted to DATE datatype |
SQL CHAR or NCHAR datatypes and ROWID datatype |
Character datatypes are converted to ROWID datatype |
SQL NCHAR and SQL CHAR datatypes |
Character values are converted to NUMBER datatype |
SQL CHAR or NCHAR datatypes and NUMBER datatype |
Character values are converted to NUMBER datatype |
SQL CHAR or NCHAR datatypes and DATE datatype |
Character values are converted to DATE datatype |
SQL CHAR or NCHAR datatypes and ROWID datatype |
Character values are converted to ROWID datatype |
SQL NCHAR datatypes and SQL CHAR datatypes |
Comparisons between SQL NCHAR datatypes and SQL CHAR datatypes are more complex because they can be encoded in different character sets.
When When When there is comparison between SQL |
SQL NCHAR
datatypes can be converted to and from SQL CHAR
datatypes and other datatypes using explicit conversion functions. The examples in this section use the table created by the following statement:
CREATE TABLE customers (id NUMBER, name NVARCHAR2(50), address NVARCHAR2(200), birthdate DATE);
Example 7-1 Populating the Customer Table Using the TO_NCHAR Function
The TO_NCHAR
function converts the data at run time, while the N
function converts the data at compilation time.
INSERT INTO customers VALUES (1000, TO_NCHAR('John Smith'),N'500 Oracle Parkway',sysdate);
Example 7-2 Selecting from the Customer Table Using the TO_CHAR Function
The following statement converts the values of name
from characters in the national character set to characters in the database character set before selecting them according to the LIKE
clause:
SELECT name FROM customers WHERE TO_CHAR(name) LIKE '%Sm%';
You should see the following output:
NAME -------------------------------------- John Smith
Example 7-3 Selecting from the Customer Table Using the TO_DATE Function
Using the N
function shows that either NCHAR
or CHAR
data can be passed as parameters for the TO_DATE
function. The datatypes can mixed because they are converted at run time.
DECLARE ndatestring NVARCHAR2(20) := N'12-SEP-1975'; BEGIN SELECT name into ndstr FROM customers WHERE (birthdate)> TO_DATE(ndatestring, 'DD-MON-YYYY', N'NLS_DATE_LANGUAGE = AMERICAN'); END;
As demonstrated in Example 7-3, SQL NCHAR
data can be passed to explicit conversion functions. SQL CHAR
and NCHAR
data can be mixed together when using multiple string parameters.
See Also: Oracle Database SQL Reference for more information about explicit conversion functions for SQLNCHAR datatypes |
Most SQL functions can take arguments of SQL NCHAR
datatypes as well as mixed character datatypes. The return datatype is based on the type of the first argument. If a non-string datatype like NUMBER
or DATE
is passed to these functions, then it is converted to VARCHAR2
. The following examples use the customer
table created in "SQL Functions for Unicode Datatypes".
Example 7-5 CONCAT Function
SELECT CONCAT(name,id) FROM customers;
id
is converted to NVARCHAR2
and then concatenated with name
.
Example 7-6 RPAD Function
SELECT RPAD(name,100,' ') FROM customers;
The following output results:
RPAD(NAME,100,'') ------------------------------------------ John Smith
Space character ' ' is converted to the corresponding character in the NCHAR
character set and then padded to the right of name
until the total display length reaches 100.
See Also: Oracle Database SQL Reference |
You can input Unicode string literals in SQL and PL/SQL as follows:
Put a prefix N
before a string literal that is enclosed with single quote marks. This explicitly indicates that the following string literal is an NCHAR
string literal. For example, N'12-SEP-1975'
is an NCHAR
string literal.
Mark a string literal with single quote marks. Because Oracle supports implicit conversions to SQL NCHAR
datatypes, a string literal is converted to a SQL NCHAR
datatype wherever necessary.
Note: When a string literal is included in a query and the query is submitted through a client-side tool such as SQL*Plus, all the queries are encoded in the client's character set and then converted to the server's database character set before processing. Therefore, data loss can occur if the string literal cannot be converted to the server database character set. |
Use the NCHR(
n
)
SQL function, which returns a unit of character code in the national character set, which is AL16UTF16 or UTF8. The result of concatenating several NCHR(
n
)
functions is NVARCHAR2
data. In this way, you can bypass the client and server character set conversions and create an NVARCHAR2
string directly. For example, NCHR(32)
represents a blank character.
Because NCHR(
n
)
is associated with the national character set, portability of the resulting value is limited to applications that run in the national character set. If this is a concern, then use the UNISTR
function to remove portability limitations.
Use the UNISTR
('string'
) SQL function. UNISTR
('string'
) converts a string to the national character set. To ensure portability and to preserve data, include only ASCII characters and Unicode encoding in the following form: \xxxx
, where xxxx
is the hexadecimal value of a character code value in UTF-16 encoding format. For example, UNISTR('G\0061ry')
represents 'Gary'
. The ASCII characters are converted to the database character set and then to the national character set. The Unicode encoding is converted directly to the national character set.
The last two methods can be used to encode any Unicode string literals.
The UTL_FILE
package was enhanced in Oracle9i to handle Unicode national character set data. The following functions and procedures were added:
FOPEN_NCHAR
This function opens a file in Unicode for input or output, with the maximum line size specified. With this function, you can read or write a text file in Unicode instead of in the database character set.
GET_LINE_NCHAR
This procedure reads text from the open file identified by the file handle and places the text in the output buffer parameter. With this procedure, you can read a text file in Unicode instead of in the database character set.
PUT_NCHAR
This procedure writes the text string stored in the buffer parameter to the open file identified by the file handle. With this procedure, you can write a text file in Unicode instead of in the database character set.
PUT_LINE_NCHAR
This procedure writes the text string stored in the buffer parameter to the open file identified by the file handle. With this procedure, you can write a text file in Unicode instead of in the database character set.
PUTF_NCHAR
This procedure is a formatted PUT_NCHAR
procedure. With this procedure, you can write a text file in Unicode instead of in the database character set.
See Also: PL/SQL Packages and Types Reference for more information about theUTL_FILE package |
OCI is the lowest-level API for accessing a database, so it offers the best possible performance. When using Unicode with OCI, consider these topics:
The OCIEnvNlsCreate()
function is used to specify a SQL CHAR
character set and a SQL NCHAR
character set when the OCI environment is created. It is an enhanced version of the OCIEnvCreate()
function and has extended arguments for two character set IDs. The OCI_UTF16ID UTF-16 character set ID replaces the Unicode mode introduced in Oracle9i release 1 (9.0.1). For example:
OCIEnv *envhp; status = OCIEnvNlsCreate((OCIEnv **)&envhp, (ub4)0, (void *)0, (void *(*) ()) 0, (void *(*) ()) 0, (void(*) ()) 0, (size_t) 0, (void **)0, (ub2)OCI_UTF16ID, /* Metadata and SQL CHAR character set */ (ub2)OCI_UTF16ID /* SQL NCHAR character set */);
The Unicode mode, in which the OCI_UTF16 flag is used with the OCIEnvCreate()
function, is deprecated.
When OCI_UTF16ID is specified for both SQL CHAR
and SQL NCHAR
character sets, all metadata and bound and defined data are encoded in UTF-16. Metadata includes SQL statements, user names, error messages, and column names. Thus, all inherited operations are independent of the NLS_LANG
setting, and all metatext data parameters (text*
) are assumed to be Unicode text datatypes (utext*
) in UTF-16 encoding.
To prepare the SQL statement when the OCIEnv()
function is initialized with the OCI_UTF16ID character set ID, call the OCIStmtPrepare()
function with a (utext*)
string. The following example runs on the Windows platform only. You may need to change wchar_t
datatypes for other platforms.
const wchar_t sqlstr[] = L"SELECT * FROM ENAME=:ename"; ... OCIStmt* stmthp; sts = OCIHandleAlloc(envh, (void **)&stmthp, OCI_HTYPE_STMT, 0, NULL); status = OCIStmtPrepare(stmthp, errhp,(const text*)sqlstr, wcslen(sqlstr), OCI_NTV_SYNTAX, OCI_DEFAULT);
To bind and define data, you do not have to set the OCI_ATTR_CHARSET_ID
attribute because the OCIEnv()
function has already been initialized with UTF-16 character set IDs. The bind variable names must be also UTF-16 strings.
/* Inserting Unicode data */ OCIBindByName(stmthp1, &bnd1p, errhp, (const text*)L":ename", (sb4)wcslen(L":ename"), (void *) ename, sizeof(ename), SQLT_STR, (void *)&insname_ind, (ub2 *) 0, (ub2 *) 0, (ub4) 0, (ub4 *)0, OCI_DEFAULT); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &ename_col_len, (ub4) 0, (ub4)OCI_ATTR_MAXDATA_SIZE, errhp); ... /* Retrieving Unicode data */ OCIDefineByPos (stmthp2, &dfn1p, errhp, (ub4)1, (void *)ename, (sb4)sizeof(ename), SQLT_STR, (void *)0, (ub2 *)0, (ub2*)0, (ub4)OCI_DEFAULT);
The OCIExecute()
function performs the operation.
See Also: "Specifying Character Sets in OCI" |
Unicode character set conversions take place between an OCI client and the database server if the client and server character sets are different. The conversion occurs on either the client or the server depending on the circumstances, but usually on the client side.
You can lose data during conversion if you call an OCI API inappropriately. If the server and client character sets are different, then you can lose data when the destination character set is a smaller set than the source character set. You can avoid this potential problem if both character sets are Unicode character sets (for example, UTF8 and AL16UTF16).
When you bind or define SQL NCHAR
datatypes, you should set the OCI_ATTR_CHARSET_FORM
attribute to SQLCS_NCHAR
. Otherwise, you can lose data because the data is converted to the database character set before converting to or from the national character set. This occurs only if the database character set is not Unicode.
Redundant data conversions can cause performance degradation in your OCI applications. These conversions occur in two cases:
When you bind or define SQL CHAR
datatypes and set the OCI_ATTR_CHARSET_FORM
attribute to SQLCS_NCHAR
, data conversions take place from client character set to the national database character set, and from the national character set to the database character set. No data loss is expected, but two conversions happen, even though it requires only one.
When you bind or define SQL NCHAR
datatypes and do not set OCI_ATTR_CHARSET_FORM
, data conversions take place from client character set to the database character set, and from the database character set to the national database character set. In the worst case, data loss can occur if the database character set is smaller than the client's.
To avoid performance problems, you should always set OCI_ATTR_CHARSET_FORM
correctly, based on the datatype of the target columns. If you do not know the target datatype, then you should set the OCI_ATTR_CHARSET_FORM
attribute to SQLCS_NCHAR
when binding and defining.
Table 7-3 contains information about OCI character set conversions.
Table 7-3 OCI Character Set Conversions
Datatypes for OCI Client Buffer | OCI_ATTR_CHARSET_FORM | Datatypes of the Target Column in the Database | Conversion Between | Comments |
---|---|---|---|---|
utext |
SQLCS_IMPLICIT |
CHAR, VARCHAR2, CLOB |
UTF-16 and database character set in OCI | No unexpected data loss |
utext |
SQLCS_NCHAR |
NCHAR, NVARCHAR2, NCLOB |
UTF-16 and national character set in OCI | No unexpected data loss |
utext |
SQLCS_NCHAR |
CHAR, VARCHAR2, CLOB |
UTF-16 and national character set in OCI
National character set and database character set in database server |
No unexpected data loss, but may degrade performance because the conversion goes through the national character set |
utext |
SQLCS_IMPLICIT |
NCHAR, NVARCHAR2, NCLOB |
UTF-16 and database character set in OCI
Database character set and national character set in database server |
Data loss may occur if the database character set is not Unicode |
text |
SQLCS_IMPLICIT |
CHAR, VARCHAR2, CLOB |
NLS_LANG character set and database character set in OCI |
No unexpected data loss |
text |
SQLCS_NCHAR |
NCHAR, NVARCHAR2, NCLOB |
NLS_LANG character set and national character set in OCI |
No unexpected data loss |
text |
SQLCS_NCHAR |
CHAR, VARCHAR2, CLOB |
NLS_LANG character set and national character set in OCI
National character set and database character set in database server |
No unexpected data loss, but may degrade performance because the conversion goes through the national character set |
text |
SQLCS_IMPLICIT |
NCHAR, NVARCHAR2, NCLOB |
NLS_LANG character set and database character set in OCI
Database character set and national character set in database server |
Data loss may occur because the conversion goes through the database character set |
Data conversion can result in data expansion, which can cause a buffer to overflow. For binding operations, you need to set the OCI_ATTR_MAXDATA_SIZE
attribute to a large enough size to hold the expanded data on the server. If this is difficult to do, then you need to consider changing the table schema. For defining operations, client applications need to allocate enough buffer space for the expanded data. The size of the buffer should be the maximum length of the expanded data. You can estimate the maximum buffer length with the following calculation:
Get the column data byte size.
Multiply it by the maximum number of bytes for each character in the client character set.
This method is the simplest and quickest way, but it may not be accurate and can waste memory. It is applicable to any character set combination. For example, for UTF-16 data binding and defining, the following example calculates the client buffer:
ub2 csid = OCI_UTF16ID; oratext *selstmt = "SELECT ename FROM emp"; counter = 1; ... OCIStmtPrepare(stmthp, errhp, selstmt, (ub4)strlen((char*)selstmt), OCI_NTV_SYNTAX, OCI_DEFAULT); OCIStmtExecute ( svchp, stmthp, errhp, (ub4)0, (ub4)0, (CONST OCISnapshot*)0, (OCISnapshot*)0, OCI_DESCRIBE_ONLY); OCIParamGet(stmthp, OCI_HTYPE_STMT, errhp, &myparam, (ub4)counter); OCIAttrGet((void*)myparam, (ub4)OCI_DTYPE_PARAM, (void*)&col_width, (ub4*)0, (ub4)OCI_ATTR_DATA_SIZE, errhp); ... maxenamelen = (col_width + 1) * sizeof(utext); cbuf = (utext*)malloc(maxenamelen); ... OCIDefineByPos(stmthp, &dfnp, errhp, (ub4)1, (void *)cbuf, (sb4)maxenamelen, SQLT_STR, (void *)0, (ub2 *)0, (ub2*)0, (ub4)OCI_DEFAULT); OCIAttrSet((void *) dfnp, (ub4) OCI_HTYPE_DEFINE, (void *) &csid, (ub4) 0, (ub4)OCI_ATTR_CHARSET_ID, errhp); OCIStmtFetch(stmthp, errhp, 1, OCI_FETCH_NEXT, OCI_DEFAULT); ...
You can use UTF8 and AL32UTF8 by setting NLS_LANG
for OCI client applications. If you do not need supplementary characters, then it does not matter whether you choose UTF8 or AL32UTF8. However, if your OCI applications might handle supplementary characters, then you need to make a decision. Because UTF8 only supports characters of up to three bytes, no supplementary character can be represented in UTF8. In AL32UTF8, one supplementary character is represented in one code point, totalling four bytes.
Do not set NLS_LANG
to AL16UTF16, because AL16UTF16 is the national character set for the server. If you need to use UTF-16, then you should specify the client character set to OCI_UTF16ID,
using the OCIAttrSet()
function when binding or defining data.
To specify a Unicode character set for binding and defining data with SQL CHAR
datatypes, you may need to call the OCIAttrSet()
function to set the appropriate character set ID after OCIBind()
or OCIDefine()
APIs. There are two typical cases:
Call OCIBind()
or OCIDefine()
followed by OCIAttrSet
() to specify UTF-16 Unicode character set encoding. For example:
... ub2 csid = OCI_UTF16ID; utext ename[100]; /* enough buffer for ENAME */ ... /* Inserting Unicode data */ OCIBindByName(stmthp1, &bnd1p, errhp, (oratext*)":ENAME", (sb4)strlen((char *)":ENAME"), (void *) ename, sizeof(ename), SQLT_STR, (void *)&insname_ind, (ub2 *) 0, (ub2 *) 0, (ub4) 0, (ub4 *)0, OCI_DEFAULT); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &csid, (ub4) 0, (ub4)OCI_ATTR_CHARSET_ID, errhp); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &ename_col_len, (ub4) 0, (ub4)OCI_ATTR_MAXDATA_SIZE, errhp); ... /* Retrieving Unicode data */ OCIDefineByPos (stmthp2, &dfn1p, errhp, (ub4)1, (void *)ename, (sb4)sizeof(ename), SQLT_STR, (void *)0, (ub2 *)0, (ub2*)0, (ub4)OCI_DEFAULT); OCIAttrSet((void *) dfn1p, (ub4) OCI_HTYPE_DEFINE, (void *) &csid, (ub4) 0, (ub4)OCI_ATTR_CHARSET_ID, errhp); ...
If bound buffers are of the utext
datatype, then you should add a cast (text
*) when OCIBind()
or OCIDefine()
is called. The value of the OCI_ATTR_MAXDATA_SIZE
attribute is usually determined by the column size of the server character set because this size is only used to allocate temporary buffer space for conversion on the server when you perform binding operations.
Call OCIBind()
or OCIDefine()
with the NLS_LANG
character set specified as UTF8 or AL32UTF8.
UTF8 or AL32UTF8 can be set in the NLS_LANG
environment variable. You call OCIBind()
and OCIDefine()
in exactly the same manner as when you are not using Unicode. Set the NLS_LANG
environment variable to UTF8 or AL32UTF8 and run the following OCI program:
... oratext ename[100]; /* enough buffer size for ENAME */ ... /* Inserting Unicode data */ OCIBindByName(stmthp1, &bnd1p, errhp, (oratext*)":ENAME", (sb4)strlen((char *)":ENAME"), (void *) ename, sizeof(ename), SQLT_STR, (void *)&insname_ind, (ub2 *) 0, (ub2 *) 0, (ub4) 0, (ub4 *)0, OCI_DEFAULT); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &ename_col_len, (ub4) 0, (ub4)OCI_ATTR_MAXDATA_SIZE, errhp); ... /* Retrieving Unicode data */ OCIDefineByPos (stmthp2, &dfn1p, errhp, (ub4)1, (void *)ename, (sb4)sizeof(ename), SQLT_STR, (void *)0, (ub2 *)0, (ub2*)0, (ub4)OCI_DEFAULT); ...
Oracle Corporation recommends that you access SQL NCHAR
datatypes using UTF-16 binding or defining when using OCI. Beginning with Oracle9i, SQL NCHAR
datatypes are Unicode datatypes with an encoding of either UTF8 or AL16UTF16. To access data in SQL NCHAR
datatypes, set the OCI_ATTR_CHARSET_FORM
attribute to SQLCS_NCHAR
between binding or defining and execution so that it performs an appropriate data conversion without data loss. The length of data in SQL NCHAR
datatypes is always in the number of Unicode code units.
The following program is a typical example of inserting and fetching data against an NCHAR
data column:
... ub2 csid = OCI_UTF16ID; ub1 cform = SQLCS_NCHAR; utext ename[100]; /* enough buffer for ENAME */ ... /* Inserting Unicode data */ OCIBindByName(stmthp1, &bnd1p, errhp, (oratext*)":ENAME", (sb4)strlen((char *)":ENAME"), (void *) ename, sizeof(ename), SQLT_STR, (void *)&insname_ind, (ub2 *) 0, (ub2 *) 0, (ub4) 0, (ub4 *)0, OCI_DEFAULT); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &cform, (ub4) 0, (ub4)OCI_ATTR_CHARSET_FORM, errhp); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &csid, (ub4) 0, (ub4)OCI_ATTR_CHARSET_ID, errhp); OCIAttrSet((void *) bnd1p, (ub4) OCI_HTYPE_BIND, (void *) &ename_col_len, (ub4) 0, (ub4)OCI_ATTR_MAXDATA_SIZE, errhp); ... /* Retrieving Unicode data */ OCIDefineByPos (stmthp2, &dfn1p, errhp, (ub4)1, (void *)ename, (sb4)sizeof(ename), SQLT_STR, (void *)0, (ub2 *)0, (ub2*)0, (ub4)OCI_DEFAULT); OCIAttrSet((void *) dfn1p, (ub4) OCI_HTYPE_DEFINE, (void *) &csid, (ub4) 0, (ub4)OCI_ATTR_CHARSET_ID, errhp); OCIAttrSet((void *) dfn1p, (ub4) OCI_HTYPE_DEFINE, (void *) &cform, (ub4) 0, (ub4)OCI_ATTR_CHARSET_FORM, errhp); ...
In order to write (bind) and read (define) UTF-16 data for CLOB
or NCLOB
columns, the UTF-16 character set ID must be specified as OCILobWrite()
and OCILobRead()
. When you write UTF-16 data into a CLOB
column, call OCILobWrite()
as follows:
... ub2 csid = OCI_UTF16ID; err = OCILobWrite (ctx->svchp, ctx->errhp, lobp, &amtp, offset, (void *) buf, (ub4) BUFSIZE, OCI_ONE_PIECE, (void *)0, (sb4 (*)()) 0, (ub2) csid, (ub1) SQLCS_IMPLICIT);
The amtp
parameter is the data length in number of Unicode code units. The offset
parameter indicates the offset of data from the beginning of the data column. The csid
parameter must be set for UTF-16 data.
To read UTF-16 data from CLOB
columns, call OCILobRead()
as follows:
... ub2 csid = OCI_UTF16ID; err = OCILobRead(ctx->svchp, ctx->errhp, lobp, &amtp, offset, (void *) buf, (ub4)BUFSIZE , (void *) 0, (sb4 (*)()) 0, (ub2)csid, (ub1) SQLCS_IMPLICIT);
The data length is always represented in the number of Unicode code units. Note one Unicode supplementary character is counted as two code units, because the encoding is UTF-16. After binding or defining a LOB
column, you can measure the data length stored in the LOB
column using OCILobGetLength()
. The returning value is the data length in the number of code units if you bind or define as UTF-16.
err = OCILobGetLength(ctx->svchp, ctx->errhp, lobp, &lenp);
If you are using an NCLOB
, then you must set OCI_ATTR_CHARSET_FORM
to SQLCS_NCHAR
.
Pro*C/C++ provides the following ways to insert or retrieve Unicode data into or from the database:
Using the VARCHAR
Pro*C/C++ datatype or the native C/C++ text
datatype, a program can access Unicode data stored in SQL CHAR
datatypes of a UTF8 or AL32UTF8 database. Alternatively, a program could use the C/C++ native text
type.
Using the UVARCHAR
Pro*C/C++ datatype or the native C/C++ utext
datatype, a program can access Unicode data stored in NCHAR
datatypes of a database.
Using the NVARCHAR
Pro*C/C++ datatype, a program can access Unicode data stored in NCHAR
datatypes. The difference between UVARCHAR
and NVARCHAR
in a Pro*C/C++ program is that the data for the UVARCHAR
datatype is stored in a utext
buffer while the data for the NVARCHAR
datatype is stored in a text
datatype.
Pro*C/C++ does not use the Unicode OCI API for SQL text. As a result, embedded SQL text must be encoded in the character set specified in the NLS_LANG
environment variable.
This section contains the following topics:
Data conversion occurs in the OCI layer, but it is the Pro*C/C++ preprocessor that instructs OCI which conversion path should be taken based on the datatypes used in a Pro*C/C++ program. Table 7-4 illustrates the conversion paths:
Table 7-4 Pro*C/C++ Bind and Define Data Conversion
Pro*C/C++ Datatype | SQL Datatype | Conversion Path |
---|---|---|
VARCHAR or text |
CHAR |
NLS_LANG character set to and from the database character set happens in OCI |
VARCHAR or text |
NCHAR |
NLS_LANG character set to and from database character set happens in OCI
Database character set to and from national character set happens in database server |
NVARCHAR |
NCHAR |
NLS_LANG character set to and from national character set happens in OCI |
NVARCHAR |
CHAR |
NLS_LANG character set to and from national character set happens in OCI
National character set to and from database character set in database server |
UVARCHAR or utext |
NCHAR |
UTF-16 to and from the national character set happens in OCI |
UVARCHAR or utext |
CHAR |
UTF-16 to and from national character set happens in OCI
National character set to database character set happens in database server |
The Pro*C/C++ VARCHAR
datatype is preprocessed to a struct with a length
field and text
buffer field. The following example uses the C/C++ text
native datatype and the VARCHAR
Pro*C/C++ datatypes to bind and define table columns.
#include <sqlca.h> main() { ... /* Change to STRING datatype: */ EXEC ORACLE OPTION (CHAR_MAP=STRING) ; text ename[20] ; /* unsigned short type */ varchar address[50] ; /* Pro*C/C++ varchar type */ EXEC SQL SELECT ename, address INTO :ename, :address FROM emp; /* ename is NULL-terminated */ printf(L"ENAME = %s, ADDRESS = %.*s\n", ename, address.len, address.arr); ... }
When you use the VARCHAR
datatype or native text
datatype in a Pro*C/C++ program, the preprocessor assumes that the program intends to access columns of SQL CHAR
datatypes instead of SQL NCHAR
datatypes in the database. The preprocessor generates C/C++ code to reflect this fact by doing a bind or define using the SQLCS_IMPLICIT
value for the OCI_ATTR_CHARSET_FORM
attribute. As a result, if a bind or define variable is bound to a column of SQL NCHAR
datatypes in the database, then implicit conversion occurs in the database server to convert the data from the database character set to the national database character set and vice versa. During the conversion, data loss occurs when the database character set is a smaller set than the national character set.
The Pro*C/C++ NVARCHAR
datatype is similar to the Pro*C/C++ VARCHAR
datatype. It should be used to access SQL NCHAR
datatypes in the database. It tells Pro*C/C++ preprocessor to bind or define a text buffer to the column of SQL NCHAR
datatypes. The preprocessor specifies the SQLCS_NCHAR
value for the OCI_ATTR_CHARSET_FORM
attribute of the bind or define variable. As a result, no implicit conversion occurs in the database.
If the NVARCHAR
buffer is bound against columns of SQL CHAR
datatypes, then the data in the NVARCHAR
buffer (encoded in the NLS_LANG
character set) is converted to or from the national character set in OCI, and the data is then converted to the database character set in the database server. Data can be lost when the NLS_LANG
character set is a larger set than the database character set.
The UVARCHAR
datatype is preprocessed to a struct with a length
field and utext
buffer field. The following example code contains two host variables, ename
and address
. The ename
host variable is declared as a utext
buffer containing 20 Unicode characters. The address
host variable is declared as a uvarchar
buffer containing 50 Unicode characters. The len
and arr
fields are accessible as fields of a struct.
#include <sqlca.h> #include <sqlucs2.h> main() { ... /* Change to STRING datatype: */ EXEC ORACLE OPTION (CHAR_MAP=STRING) ; utext ename[20] ; /* unsigned short type */ uvarchar address[50] ; /* Pro*C/C++ uvarchar type */ EXEC SQL SELECT ename, address INTO :ename, :address FROM emp; /* ename is NULL-terminated */ wprintf(L"ENAME = %s, ADDRESS = %.*s\n", ename, address.len, address.arr); ... }
When you use the UVARCHAR
datatype or native utext
datatype in Pro*C/C++ programs, the preprocessor assumes that the program intends to access SQL NCHAR
datatypes. The preprocessor generates C/C++ code by binding or defining using the SQLCS_NCHAR
value for OCI_ATTR_CHARSET_FORM
attribute. As a result, if a bind or define variable is bound to a column of a SQL NCHAR
datatype, then an implicit conversion of the data from the national character set occurs in the database server. However, there is no data lost in this scenario because the national character set is always a larger set than the database character set.
Oracle provides the following JDBC drivers for Java programs to access character data in an Oracle database:
The JDBC OCI driver
The JDBC thin driver
The JDBC server-side internal driver
The JDBC server-side thin driver
Java programs can insert or retrieve character data to and from columns of SQL CHAR
and NCHAR
datatypes. Specifically, JDBC enables Java programs to bind or define Java strings to SQL CHAR
and NCHAR
datatypes. Because Java's string
datatype is UTF-16 encoded, data retrieved from or inserted into the database must be converted from UTF-16 to the database character set or the national character set and vice versa. JDBC also enables you to specify the PL/SQL and SQL statements in Java strings so that any non-ASCII schema object names and string literals can be used.
At database connection time, JDBC sets the server NLS_LANGUAGE
and NLS_TERRITORY
parameters to correspond to the locale of the Java VM that runs the JDBC driver. This operation ensures that the server and the Java client communicate in the same language. As a result, Oracle error messages returned from the server are in the same language as the client locale.
This section contains the following topics:
Oracle JDBC drivers allow you to access SQL CHAR
datatypes in the database using Java string bind or define variables. The following code illustrates how to bind a Java string to a CHAR
column.
int employee_id = 12345; String last_name = "Joe"; PreparedStatement pstmt = conn.prepareStatement("INSERT INTO" + "employees (last_name, employee_id) VALUES (?, ?)"); pstmt.setString(1, last_name); pstmt.setInt(2, employee_id); pstmt.execute(); /* execute to insert into first row */ employee_id += 1; /* next employee number */ last_name = "\uFF2A\uFF4F\uFF45"; /* Unicode characters in name */ pstmt.setString(1, last_name); pstmt.setInt(2, employee_id); pstmt.execute(); /* execute to insert into second row */
You can define the target SQL columns by specifying their datatypes and lengths. When you define a SQL CHAR
column with the datatype and the length, JDBC uses this information to optimize the performance of fetching SQL CHAR
data from the column. The following is an example of defining a SQL CHAR
column.
OraclePreparedStatement pstmt = (OraclePreparedStatement) conn.prepareStatement("SELECT ename, empno from emp"); pstmt.defineColumnType(1,Types.VARCHAR, 3); pstmt.defineColumnType(2,Types.INTEGER); ResultSet rest = pstmt.executeQuery(); String name = rset.getString(1); int id = reset.getInt(2);
You need to cast PreparedStatement
to OraclePreparedStatement
to call defineColumnType()
. The second parameter of defineColumnType()
is the datatype of the target SQL column. The third parameter is the length in number of characters.
For binding or defining Java string variables to SQL NCHAR
datatypes, Oracle provides an extended PreparedStatement
which has the setFormOfUse()
method through which you can explicitly specify the target column of a bind variable to be a SQL NCHAR
datatype. The following code illustrates how to bind a Java string to an NCHAR
column.
int employee_id = 12345; String last_name = "Joe" oracle.jdbc.OraclePreparedStatement pstmt = (oracle.jdbc.OraclePreparedStatement) conn.prepareStatement("INSERT INTO employees (last_name, employee_id) VALUES (?, ?)"); pstmt.setFormOfUse(1, oracle.jdbc.OraclePreparedStatement.FORM_NCHAR); pstmt.setString(1, last_name); pstmt.setInt(2, employee_id); pstmt.execute(); /* execute to insert into first row */ employee_id += 1; /* next employee number */ last_name = "\uFF2A\uFF4F\uFF45"; /* Unicode characters in name */ pstmt.setString(1, last_name); pstmt.setInt(2, employee_id); pstmt.execute(); /* execute to insert into second row */
You can define the target SQL NCHAR
columns by specifying their datatypes, forms of use, and lengths. JDBC uses this information to optimize the performance of fetching SQL NCHAR
data from these columns. The following is an example of defining a SQL NCHAR
column.
OraclePreparedStatement pstmt = (OraclePreparedStatement) conn.prepareStatement("SELECT ename, empno from emp"); pstmt.defineColumnType(1,Types.VARCHAR, 3, OraclePreparedStatement.FORM_NCHAR); pstmt.defineColumnType(2,Types.INTEGER); ResultSet rest = pstmt.executeQuery(); String name = rset.getString(1); int id = reset.getInt(2);
To define a SQL NCHAR
column, you need to specify the datatype that is equivalent to a SQL CHAR
column in the first argument, the length in number of characters in the second argument, and the form of use in the fourth argument of defineColumnType()
.
You can bind or define a Java string against an NCHAR
column without explicitly specifying the form of use argument. This implies the following:
If you do not specify the argument in the setString()
method, then JDBC assumes that the bind or define variable is for the SQL CHAR
column. As a result, it tries to convert them to the database character set. When the data gets to the database, the database implicitly converts the data in the database character set to the national character set. During this conversion, data can be lost when the database character set is a subset of the national character set. Because the national character set is either UTF8 or AL16UTF16, data loss would happen if the database character set is not UTF8 or AL32UTF8.
Because implicit conversion from SQL CHAR
to SQL NCHAR
datatypes happens in the database, database performance is degraded.
In addition, if you bind or define a Java string for a column of SQL CHAR
datatypes but specify the form of use argument, then performance of the database is degraded. However, data should not be lost because the national character set is always a larger set than the database character set.
A global flag has been introduced in the Oracle JDBC drivers for customers to tell whether the form of use argument should be specified by default in a Java application. This flag has the following purposes:
Existing applications accessing the SQL CHAR
datatypes can be migrated to support the SQL NCHAR
datatypes for worldwide deployment without changing a line of code.
Applications do not need to call the setFormOfUse()
method when binding and defining a SQL NCHAR
column. The application code can be made neutral and independent of the datatypes being used in the backend database. With this flag, applications can be easily switched from using SQL CHAR
or SQL NCHAR
.
The global flag is specified in the command line that invokes the Java application. The syntax of specifying this flag is as follows:
java -Doracle.jdbc.defaultNChar=true <application class>
With this flag specified, the Oracle JDBC drivers assume the presence of the form of use argument for all bind and define operations in the application.
If you have a database schema that consists of both the SQL CHAR
and SQL NCHAR
columns, then using this flag may have some performance impact when accessing the SQL CHAR
columns because of implicit conversion done in the database server.
See Also: "Data Conversion in JDBC" for more information about the performance impact of implicit conversion |
Because Java strings are always encoded in UTF-16, JDBC drivers transparently convert data from the database character set to UTF-16 or the national character set. The conversion paths taken are different for the JDBC drivers:
For the OCI driver, the SQL statements are always converted to the database character set by the driver before it is sent to the database for processing. When the database character set is neither US7ASCII nor WE8ISO8859P1, the driver converts the SQL statements to UTF-8 first in Java and then to the database character set in C. Otherwise, it converts the SQL statements directly to the database character set. For Java string bind or define variables, Table 7-5 summarizes the conversion paths taken for different scenarios.
Table 7-5 OCI Driver Conversion Path
Form of Use | SQL Datatype | Conversion Path |
---|---|---|
Const.CHAR (Default) |
CHAR |
Java string to and from database character set happens in the JDBC driver |
Const.CHAR (Default) |
NCHAR |
Java string to and from database character set happens in the JDBC driver.
Data in the database character set to and from national character set happens in the database server |
Const.NCHAR |
NCHAR |
Java string to and from national character set happens in the JDBC driver |
Const.NCHAR |
CHAR |
Java string to and from national character set happens in the JDBC driver
Data in national character set to and from database character set happens in the database server |
SQL statements are always converted to either the database character set or to UTF-8 by the driver before they are sent to the database for processing. When the database character set is either US7ASCII or WE8ISO8859P1, the driver converts the SQL statement to the database character set. Otherwise, the driver converts the SQL statement to UTF-8 and notifies the database that a SQL statement requires further conversion before being processed. The database, in turn, converts the SQL statements from UTF-8 to the database character set. The database, in turn, converts the SQL statement to the database character set. For Java string bind and define variables, the conversion paths shown in Table 7-6 are taken for the thin driver.
Table 7-6 Thin Driver Conversion Path
Form of Use | SQL Datatype | Database Character Set | Conversion Path |
---|---|---|---|
Const.CHAR (Default) |
CHAR |
US7ASCII or WE8ISO8859P1 | Java string to and from the database character set happens in the thin driver. |
Const.CHAR (Default) |
NCHAR |
US7ASCII or WE8ISO8859P1 | Java string to and from the database character set happens in the thin driver.
Data in the database character set to and from the national character set happens in the database server. |
Const.CHAR (Default) |
CHAR |
non-ASCII and non-WE8ISO8859P1 | Java string to and from UTF-8 happens in the thin driver.
Data in UTF-8 to and from the database character set happens in the database server. |
Const.CHAR (Default) |
NCHAR |
non-ASCII and non-WE8ISO8859P1 | Java string to and from UTF-8 happens in the thin driver.
Data in UTF-8 to and from national character set happens in the database server. |
Const.NCHAR |
CHAR |
Java string to and from the national character set happens in the thin driver.
Data in the national character set to and from the database character set happens in the database server. |
|
Const.NCHAR |
NCHAR |
Java string to and from the national character set happens in the thin driver. |
JDBC drivers support Oracle object types. Oracle objects are always sent from database to client as an object represented in the database character set or national character set. That means the data conversion path in "Data Conversion in JDBC" does not apply to Oracle object access. Instead, the oracle.sql.CHAR
class is used for passing SQL CHAR
and SQL NCHAR
data of an object type from the database to the client.
This section includes the following topics:
The oracle.sql.CHAR
class has a special functionality for conversion of character data. The Oracle character set is a key attribute of the oracle.sql.CHAR
class. The Oracle character set is always passed in when an oracle.sql.CHAR
object is constructed. Without a known character set, the bytes of data in the oracle.sql.CHAR
object are meaningless.
The oracle.sql.CHAR
class provides the following methods for converting character data to strings:
Converts the sequence of characters represented by the oracle.sql.CHAR
object to a string, returning a Java string object. If the character set is not recognized, then getString()
returns a SQLException
.
Identical to getString()
, except that if the character set is not recognized, then toString()
returns a hexadecimal representation of the oracle.sql.CHAR
data and does not returns a SQLException
.
Identical to getString()
, except that a default replacement character replaces characters that have no Unicode representation in the character set of this oracle.sql.CHAR
object. This default character varies among character sets, but it is often a question mark.
You may want to construct an oracle.sql.CHAR
object yourself (to pass into a prepared statement, for example). When you construct an oracle.sql.CHAR
object, you must provide character set information to the oracle.sql.CHAR
object by using an instance of the oracle.sql.CharacterSet
class. Each instance of the oracle.sql.CharacterSet
class represents one of the character sets that Oracle supports.
Complete the following tasks to construct an oracle.sql.CHAR
object:
Create a CharacterSet
instance by calling the static CharacterSet.make()
method. This method creates the character set class. It requires as input a valid Oracle character set (OracleId)
. For example:
int OracleId = CharacterSet.JA16SJIS_CHARSET; // this is character set 832 ... CharacterSet mycharset = CharacterSet.make(OracleId);
Each character set that Oracle supports has a unique predefined OracleId
. The OracleId
can always be referenced as a character set specified as Oracle_character_set_name
_CHARSET
where Oracle_character_set_name
is the Oracle character set.
Construct an oracle.sql.CHAR
object. Pass to the constructor a string (or the bytes that represent the string) and the CharacterSet
object that indicates how to interpret the bytes based on the character set. For example:
String mystring = "teststring"; ... oracle.sql.CHAR mychar = new oracle.sql.CHAR(teststring, mycharset);
The oracle.sql.CHAR
class has multiple constructors: they can take a string, a byte array, or an object as input along with the CharacterSet
object. In the case of a string, the string is converted to the character set indicated by the CharacterSet
object before being placed into the oracle.sql.CHAR
object.
The server (database) and the client (or application running on the client) can use different character sets. When you use the methods of this class to transfer data between the server and the client, the JDBC drivers must convert the data between the server character set and the client character set.
The following is an example of an object type created using SQL:
CREATE TYPE person_type AS OBJECT (name VARCHAR2(30), address NVARCHAR(256), age NUMBER); CREATE TABLE employees (id NUMBER, person PERSON_TYPE);
The Java class corresponding to this object type can be constructed as follows:
public class person implement SqlData { oracle.sql.CHAR name; oracle.sql.CHAR address; oracle.sql.NUMBER age; // SqlData interfaces getSqlType() {...} writeSql(SqlOutput stream) {...} readSql(SqlInput stream, String sqltype) {...} }
The oracle.sql.CHAR
class is used here to map to the NAME
attributes of the Oracle object type, which is of VARCHAR2
datatype. JDBC populates this class with the byte representation of the VARCHAR2
data in the database and the CharacterSet
object corresponding to the database character set. The following code retrieves a person
object from the employees
table:
TypeMap map = ((OracleConnection)conn).getTypeMap(); map.put("PERSON_TYPE", Class.forName("person")); conn.setTypeMap(map); . . . . . . ResultSet rs = stmt.executeQuery("SELECT PERSON FROM EMPLOYEES"); rs.next(); person p = (person) rs.getObject(1); oracle.sql.CHAR sql_name = p.name; oracle.sql.CHAR sql_address=p.address; String java_name = sql_name.getString(); String java_address = sql_address.getString();
The getString()
method of the oracle.sql.CHAR
class converts the byte array from the database character set or national character set to UTF-16 by calling Oracle's Java data conversion classes and returning a Java string. For the rs.getObject(1)
call to work, the SqlData
interface has to be implemented in the class person
, and the Typemap
map
has to be set up to indicate the mapping of the object type PERSON_TYPE
to the Java class.
This section contains the following topics:
If the database character set is neither ASCII (US7ASCII) nor ISO Latin1 (WE8ISO8859P1), then the JDBC thin driver must impose size restrictions for SQL CHAR
bind parameters that are more restrictive than normal database size limitations. This is necessary to allow for data expansion during conversion.
The JDBC thin driver checks SQL CHAR
bind sizes when a set
XXX
()
method (except for the setCharacterStream()
method) is called. If the data size exceeds the size restriction, then the driver returns a SQL exception (SQLException: Data size bigger than max size for this type"
) from the set
XXX
()
call. This limitation is necessary to avoid the chance of data corruption when conversion of character data occurs and increases the length of the data. This limitation is enforced in the following situations:
Using the JDBC thin driver
Using binds (not defines)
Using SQL CHAR
datatypes
Connecting to a database whose character set is neither ASCII (US7ASCII) nor ISO Latin1 (WE8ISO8859P1)
When the database character set is neither US7ASCII nor WE8ISO8859P1, the JDBC thin driver converts Java UTF-16 characters to UTF-8 encoding bytes for SQL CHAR
binds. The UTF-8 encoding bytes are then transferred to the database, and the database converts the UTF-8 encoding bytes to the database character set encoding.
This conversion to the character set encoding can result in an increase in the number of bytes required to store the data. The expansion factor for a database character set indicates the maximum possible expansion in converting from UTF-8 to the character set. If the database character set is either UTF8 or AL32UTF8, then the expansion factor (exp_factor
) is 1
. Otherwise, the expansion factor is equal to the maximum character size (measured in bytes) in the database character set.
Table 7-7 shows the database size limitations for SQL CHAR
data and the JDBC thin driver size restriction formulas for SQL CHAR
binds. Database limits are in bytes. Formulas determine the maximum allowed size of the UTF-8 encoding in bytes.
Table 7-7 Maximum SQL CHAR Bind Sizes
Datatype | Maximum Bind Size Allowed by Database | Formula for Determining the Maximum Bind Size, Measured in UTF-8 Bytes |
---|---|---|
CHAR |
2000 bytes | 4000/ exp_factor |
VARCHAR2 |
4000 bytes | 4000/ exp_factor |
LONG |
231 - 1 bytes | (2 31 - 1)/ exp_factor |
The formulas guarantee that after the data is converted from UTF-8 to the database character set, the size of the data does not exceed the maximum size allowed in the database.
The number of UTF-16 characters that can be supported is determined by the number of bytes for each character in the data. All ASCII characters are one byte long in UTF-8 encoding. Other character types can be two or three bytes long.
Table 7-8 lists the expansion factors of some common server character sets. It also shows the JDBC thin driver maximum bind sizes for CHAR
and VARCHAR2
data for each character set.
Oracle JDBC drivers perform character set conversions as appropriate when character data is inserted into or retrieved from the database. The drivers convert Unicode characters used by Java clients to Oracle database character set characters, and vice versa. Character data that makes a round trip from the Java Unicode character set to the database character set and back to Java can suffer some loss of information. This happens when multiple Unicode characters are mapped to a single character in the database character set. An example is the Unicode full-width tilde character (0xFF5E) and its mapping to Oracle's JA16SJIS character set. The round-trip conversion for this Unicode character results in the Unicode character 0x301C, which is a wave dash (a character commonly used in Japan to indicate range), not a tilde.
Figure 7-2 shows the round-trip conversion of the tilde character.
This issue is not a bug in Oracle's JDBC. It is an unfortunate side effect of the ambiguity in character mapping specification on different operating systems. Fortunately, this problem affects only a small number of characters in a small number of Oracle character sets such as JA16SJIS, JA16EUC, ZHT16BIG5, and KO16KS5601. The workaround is to avoid making a full round-trip with these characters.
You should use the Oracle ODBC driver or Oracle Provider for OLE DB to access the Oracle server when using a Windows platform. This section describes how these drivers support Unicode. It includes the following topics:
Oracle's ODBC driver and Oracle Provider for OLE DB can handle Unicode data properly without data loss. For example, you can run a Unicode ODBC application containing Japanese data on English Windows if you install Japanese fonts and an input method editor for entering Japanese characters.
Oracle provides ODBC and OLE DB products for Windows platforms only. For Unix platforms, contact your vendor.
OCI Unicode binding and defining features are used by the ODBC and OLE DB drivers to handle Unicode data. OCI Unicode data binding and defining features are independent from NLS_LANG
. This means Unicode data is handled properly, irrespective of the NLS_LANG
setting on the platform.
See Also: "OCI Programming with Unicode" |
In general, no redundant data conversion occurs unless you specify a different client datatype from that of the server. If you bind Unicode buffer SQL_C_WCHAR
with a Unicode data column like NCHAR
, for example, then ODBC and OLE DB drivers bypass it between the application and OCI layer.
If you do not specify datatypes before fetching, but call SQLGetData
with the client datatypes instead, then the conversions in Table 7-9 occur.
Table 7-9 ODBC Implicit Binding Code Conversions
Datatypes of ODBC Client Buffer | Datatypes of the Target Column in the Database | Fetch Conversions | Comments |
---|---|---|---|
SQL_C_WCHAR |
CHAR, VARCHAR2, CLOB |
If the database character set is a subset of the NLS_LANG character set, then the conversions occur in the following order:
|
No unexpected data loss
May degrade performance if database character set is a subset of the |
SQL_C_CHAR |
CHAR, VARCHAR2, CLOB |
If database character set is a subset of NLS_LANG character set:
Database character set to If database character set is NOT a subset of Database character set, UTF-16, to |
No unexpected data loss
May degrade performance if database character set is not a subset of |
You must specify the datatype for inserting and updating operations.
The datatype of the ODBC client buffer is given when you call SQLGetData
but not immediately. Hence, SQLFetch
does not have the information.
Because the ODBC driver guarantees data integrity, if you perform implicit bindings, then redundant conversion may result in performance degradation. Your choice is the trade-off between performance with explicit binding or usability with implicit binding.
Unlike ODBC, OLE DB only enables you to perform implicit bindings for inserting, updating, and fetching data. The conversion algorithm for determining the intermediate character set is the same as the implicit binding cases of ODBC.
Table 7-10 OLE DB Implicit Bindings
Datatypes of OLE_DB Client Buffer | Datatypes of the Target Column in the Database | In-Binding and Out-Binding Conversions | Comments |
---|---|---|---|
DBTYPE_WCHAR |
CHAR, VARCHAR2, CLOB |
If database character set is a subset of the NLS_LANG character set:
Database character set to and from If database character set is NOT a subset of Database character set to and from UTF-16 in OCI |
No unexpected data loss
May degrade performance if database character set is a subset of |
DBTYPE_CHAR |
CHAR, VARCHAR2, CLOB |
If database character set is a subset of the NLS_LANG character set:
Database character set to and from If database character set is not a subset of Database character set to and from UTF-16 in OCI. UTF-16 to |
No unexpected data loss
May degrade performance if database character set is not a subset of |
In ODBC Unicode applications, use SQLWCHAR
to store Unicode data. All standard Windows Unicode functions can be used for SQLWCHAR
data manipulations. For example, wcslen
counts the number of characters of SQLWCHAR
data:
SQLWCHAR sqlStmt[] = L"select ename from emp"; len = wcslen(sqlStmt);
Microsoft's ODBC 3.5 specification defines three Unicode datatype identifiers for the SQL_C_WCHAR
, SQL_C_WVARCHAR
, and SQL_WLONGVARCHAR
clients; and three Unicode datatype identifiers for servers SQL_WCHAR
, SQL_WVARCHAR
, and SQL_WLONGVARCHAR
.
For binding operations, specify datatypes for both client and server using SQLBindParameter
. The following is an example of Unicode binding, where the client buffer Name
indicates that Unicode data (SQL_C_WCHAR
) is bound to the first bind variable associated with the Unicode column (SQL_WCHAR
):
SQLBindParameter(StatementHandle, 1, SQL_PARAM_INPUT, SQL_C_WCHAR, SQL_WCHAR, NameLen, 0, (SQLPOINTER)Name, 0, &Name);
Table 7-11 represents the datatype mappings of the ODBC Unicode datatypes for the server against SQL NCHAR
datatypes.
Table 7-11 Server ODBC Unicode Datatype Mapping
ODBC Datatype | Oracle Datatype |
---|---|
SQL_WCHAR |
NCHAR |
SQL_WVARCHAR |
NVARCHAR2 |
SQL_WLONGVARCHAR |
NCLOB |
According to ODBC specifications, SQL_WCHAR
, SQL_WVARCHAR
, and SQL_WLONGVARCHAR
are treated as Unicode data, and are therefore measured in the number of characters instead of the number of bytes.
OLE DB offers the wchar_t
, BSTR
, and OLESTR
datatypes for a Unicode C client. In practice, wchar_t
is the most common datatype and the others are for specific purposes. The following example assigns a static SQL statement:
wchar_t *sqlStmt = OLESTR("SELECT ename FROM emp");
The OLESTR
macro works exactly like an "L" modifier to indicate the Unicode string. If you need to allocate Unicode data buffer dynamically using OLESTR
, then use the IMalloc
allocator (for example, CoTaskMemAlloc
). However, using OLESTR
is not the normal method for variable length data; use wchar_t
* instead for generic string types. BSTR
is similar. It is a string with a length prefix in the memory location preceding the string. Some functions and methods can accept only BSTR
Unicode datatypes. Therefore, BSTR
Unicode string must be manipulated with special functions like SysAllocString
for allocation and SysFreeString
for freeing memory.
Unlike ODBC, OLE DB does not allow you to specify the server datatype explicitly. When you set the client datatype, the OLE DB driver automatically performs data conversion if necessary.
Table 7-12 illustrates OLE DB datatype mapping.
If DBTYPE_BSTR
is specified, then it is assumed to be DBTYPE_WCHAR
because both are Unicode strings.
ADO is a high-level API to access database with the OLE DB and ODBC drivers. Most database application developers use the ADO interface on Windows because it is easily accessible from Visual Basic, the primary scripting language for Active Server Pages (ASP) for the Internet Information Server (IIS). To OLE DB and ODBC drivers, ADO is simply an OLE DB consumer or ODBC application. ADO assumes that OLE DB and ODBC drivers are Unicode-aware components; hence, it always attempts to manipulate Unicode data.
XML support of Unicode is essential for software development for global markets so that text information can be exchanged in any language. Unicode uniformly supports almost every character and language, which makes it much easier to support multiple languages within XML. To enable Unicode for XML within an Oracle database, the character set of the database must be UTF-8. By enabling Unicode text handling in your application, you acquire a basis for supporting any language. Every XML document is Unicode text and potentially multilingual, unless it is guaranteed that only a known subset of Unicode characters will appear on your documents. Thus Oracle recommends that you enable Unicode for XML. Unicode support comes with Java and many other modern programming environments.
This section includes the following topics:
A common mistake in reading and writing XML files is using the Reader
and Writer
classes for character input and output. Using Reader
and Writer
for XML files should be avoided because it requires character set conversion based on the default character encoding of the runtime environment.
For example, using FileWriter
class is not safe because it converts the document to the default character encoding. The output file can suffer from a parsing error or data loss if the document contains characters that are not available in the default character encoding.
UTF-8 is popular for XML documents, but UTF-8 is not usually the default file encoding for Java. Thus using a Java class that assumes the default file encoding can cause problems.
The following example shows how to avoid these problems:
import java.io.*; import oracle.xml.parser.v2.*; public class I18nSafeXMLFileWritingSample { public static void main(String[] args) throws Exception { // create a test document XMLDocument doc = new XMLDocument(); doc.setVersion( "1.0" ); doc.appendChild(doc.createComment( "This is a test empty document." )); doc.appendChild(doc.createElement( "root" )); // create a file File file = new File( "myfile.xml" ); // create a binary output stream to write to the file just created FileOutputStream fos = new FileOutputStream( file ); // create a Writer that converts Java character stream to UTF-8 stream OutputStreamWriter osw = new OutputStreamWriter( fos, "UTF8" ); // buffering for efficiency Writer w = new BufferedWriter( osw ); // create a PrintWriter to adapt to the printing method PrintWriter out = new PrintWriter( w ); // print the document to the file through the connected objects doc.print( out ); } }
Do not read XML files as text input. When reading an XML document stored in a file system, use the parser to automatically detect the character encoding of the document. Avoid using a Reader
class or specifying a character encoding on the input stream. Given a binary input stream with no external encoding information, the parser automatically figures out the character encoding based on the byte order mark and encoding declaration of the XML document. Any well-formed document in any supported encoding can be successfully parsed using the following sample code:
import java.io.*; import oracle.xml.parser.v2.*; public class I18nSafeXMLFileReadingSample { public static void main(String[] args) throws Exception { // create an instance of the xml file File file = new File( "myfile.xml" ); // create a binary input stream FileInputStream fis = new FileInputStream( file ); // buffering for efficiency BufferedInputStream in = new BufferedInputStream( fis ); // get an instance of the parser DOMParser parser = new DOMParser(); // parse the xml file parser.parse( in ); } }
When the source of an XML document is not a file system, the encoding information is usually available before reading the document. For example, if the input document is provided in the form of a Java character stream or Reader, its encoding is evident and no detection should take place. The parser can begin parsing a Reader in Unicode without regard to the character encoding.
The following is an example of parsing a document with external encoding information:
import java.io.*; import java.net.*; import org.xml.sax.*; import oracle.xml.parser.v2.*; public class I18nSafeXMLStreamReadingSample { public static void main(String[] args) throws Exception { // create an instance of the xml file URL url = new URL( "http://myhost/mydocument.xml" ); // create a connection to the xml document URLConnection conn = url.openConnection(); // get an input stream InputStream is = conn.getInputStream(); // buffering for efficiency BufferedInputStream bis = new BufferedInputStream( is ); /* figure out the character encoding here */ /* a typical source of encoding information is the content-type header */ /* we assume it is found to be utf-8 in this example */ String charset = "utf-8"; // create an InputSource for UTF-8 stream InputSource in = new InputSource( bis ); in.setEncoding( charset ); // get an instance of the parser DOMParser parser = new DOMParser(); // parse the xml stream parser.parse( in ); } }