Oracle8 SQL Reference Release 8.0 A58225-01 |
|
This chapter contains reference information on the basic elements of Oracle SQL.
Before using any of the commands described in Chapter 4, "Commands", you should familiarize yourself with the concepts covered in this chapter:
The terms literal and constant value are synonymous and refer to a fixed data value. For example, 'JACK', 'BLUE ISLAND', and '101' are all character literals; 5001 is a numeric literal. Note that character literals are enclosed in single quotation marks, which enable Oracle to distinguish them from schema object names.
Many SQL statements and functions require you to specify character and numeric literal values. You can also specify literals as part of expressions and conditions. You can specify character literals with the 'text' notation, national character literals with the N'text' notation, and numeric literals with the integer or number notation, depending on the context of the literal. The syntactic forms of these notations appear in the following sections.
Text specifies a text or character literal. You must use this notation to specify values whenever 'text' or char appear in expressions, conditions, SQL functions, and SQL commands in other parts of this reference.
The syntax of text is as follows:
text::=
where
A text literal must be enclosed in single quotation marks. This reference uses the terms text literal and character literal interchangeably.
Text literals have properties of both the CHAR and VARCHAR2 datatypes:
Here are some valid text literals:
'Hello' 'ORACLE.dbs' 'Jackie''s raincoat' '09-MAR-92' N'nchar literal'
For more information, see the syntax description of expr in "Expressions".
You must use the integer notation to specify an integer whenever integer appears in expressions, conditions, SQL functions, and SQL commands described in other parts of this reference.
The syntax of integer is as follows:
integer::=
where
digit |
is one of 0, 1, 2, 3, 4, 5, 6, 7, 8, 9. |
An integer can store a maximum of 38 digits of precision.
Here are some valid integers:
7 +255
For more information, see the syntax description of expr in "Expressions".
You must use the number notation to specify values whenever number appears in expressions, conditions, SQL functions, and SQL commands in other parts of this reference.
The syntax of number is as follows:
number::=
where
A number can store a maximum of 38 digits of precision.
If you have established a decimal character other than a period (.) with the initialization parameter NLS_NUMERIC_CHARACTERS, you must specify numeric literals with 'text' notation. In such cases, Oracle automatically converts the text literal to a numeric value.
For example, if the NLS_NUMERIC_CHARACTERS parameter specifies a decimal character of comma, specify the number 5.123 as follows:
'5,123'
For more information on this parameter, see Oracle8 Reference.
Here are some valid representations of number:
25 +6.34 0.5 25e-03 -1
For more information, see the syntax description of expr in "Expressions".
Each literal or column value manipulated by Oracle has a datatype. A value's datatype associates a fixed set of properties with the value. These properties cause Oracle to treat values of one datatype differently from values of another. For example, you can add values of NUMBER datatype, but not values of RAW datatype.
When you create a table or cluster, you must specify an internal datatype for each of its columns. When you create a procedure or stored function, you must specify an internal datatype for each of its arguments. These datatypes define the domain of values that each column can contain or each argument can have. For example, DATE columns cannot accept the value February 29 (except for a leap year) or the values 2 or 'SHOE'. Each value subsequently placed in a column assumes the column's datatype. For example, if you insert '01-JAN-92' into a DATE column, Oracle treats the '01-JAN-92' character string as a DATE value after verifying that it translates to a valid date.
Table 2-1 summarizes Oracle internal datatypes. The rest of this section describes these datatypes in detail.
Note: The Oracle precompilers recognize other datatypes in embedded SQL programs. These datatypes are called external datatypes and are associated with host variables. Do not confuse the internal datatypes with external datatypes. For information on external datatypes, including how Oracle converts between internal and external datatypes, see Pro*COBOL Precompiler Programmer's Guide, Pro*C/C++ Precompiler Programmer's Guide, and SQL*Module for Ada Programmer's Guide. |
The codes listed for the datatypes are used internally by Oracle. The datatype code of a column or object attribute is returned when you use the DUMP function.
Character datatypes store character (alphanumeric) data-words and free-form text-in the database or national character set. They are less restrictive than other datatypes and consequently have fewer properties. For example, character columns can store all alphanumeric values, but NUMBER columns can store only numeric values.
Character data is stored in strings with byte values corresponding to one of the character sets, such as 7-bit ASCII or EBCDIC Code Page 500, specified when the database was created. Oracle supports both single-byte and multibyte character sets.
These datatypes are used for character data:
The CHAR datatype specifies a fixed-length character string. When you create a table with a CHAR column, you supply the column length in bytes. Oracle subsequently ensures that all values stored in that column have this length. If you insert a value that is shorter than the column length, Oracle blank-pads the value to column length. If you try to insert a value that is too long for the column, Oracle returns an error.
The default length for a CHAR column is 1 character and the maximum allowed is 2000 characters. A zero-length string can be inserted into a CHAR column, but the column is blank-padded to 1 character when used in comparisons. For information on comparison semantics, see "Datatype Comparison Rules".
The NCHAR datatype specifies a fixed-length national character set character string. When you create a table with an NCHAR column, you define the column length either in characters or in bytes. You define the national character set when you create your database.
If the national character set specified is fixed width, such as JA16EUCFIXED, then you declare the NCHAR column size as the number of characters desired for the string length. If the national character set is variable width, such as JA16SJIS, you declare the column size in bytes. The following statement creates a table with one NCHAR column that can store strings up to 30 characters in length using JA16EUCFIXED as the national character set:
CREATE TABLE tab1 (col1 NCHAR(30));
The column's maximum length is determined by the national character set definition. Width specifications of character datatype NCHAR refer to the number of characters if the national character set is fixed width and refer to the number of bytes if the national character set is variable width. The maximum column size allowed is 2000 bytes. For fixed-width, multibyte character sets, the maximum length of a column allowed is the number of characters that fit into no more than 2000 bytes.
If you insert a value that is shorter than the column length, Oracle blank-pads the value to column length. You cannot insert a CHAR value into an NCHAR column, nor can you insert an NCHAR value into a CHAR column.
The following example compares the col1
column of tab1
with national character set string NCHAR literal:
SELECT * FROM tab1 WHERE col1 = N'NCHAR literal';
You cannot create an object with NCHAR attributes, but you can specify NCHAR parameters in methods.
The NVARCHAR2 datatype specifies a variable-length national character set character string. When you create a table with an NVARCHAR2 column, you supply the maximum number of characters or bytes that it can hold. Oracle subsequently stores each value in the column exactly as you specify it, provided it does not exceed the column's maximum length.
The column's maximum length is determined by the national character set definition. Width specifications of character datatype NVARCHAR2 refer to the number of characters if the national character set is fixed width and refer to the number of bytes if the national character set is variable width. The maximum column size allowed is 4000 bytes. For fixed-width, multibyte character sets, the maximum length of a column allowed is the number of characters that fit into no more than 4000 bytes.
The following statement creates a table with one NVARCHAR2 column of 2000 characters in length (stored as 4000 bytes, because each character takes two bytes) using JA16EUCFIXED as the national character set:
CREATE TABLE tab1 (col1 NVARCHAR2(2000));
You cannot create an object with NVARCHAR2 attributes, but you can specify NVARCHAR2 parameters in methods.
The VARCHAR2 datatype specifies a variable-length character string. When you create a VARCHAR2 column, you can supply the maximum number of bytes of data that it can hold. Oracle subsequently stores each value in the column exactly as you specify it, provided it does not exceed the column's maximum length. This maximum must be at least 1 byte, although the actual length of the string stored is permitted to be zero. If you try to insert a value that exceeds the specified length, Oracle returns an error.
You must specify a maximum length for a VARCHAR2 column. The maximum length of VARCHAR2 data is 4000 bytes. Oracle compares VARCHAR2 values using nonpadded comparison semantics. For information on comparison semantics, see "Datatype Comparison Rules".
The VARCHAR datatype is currently synonymous with the VARCHAR2 datatype. Oracle recommends that you use VARCHAR2 rather than VARCHAR. In the future, VARCHAR might be defined as a separate datatype used for variable-length character strings compared with different comparison semantics.
The NUMBER datatype stores zero, positive and negative fixed and floating-point numbers with magnitudes between 1.0 x 10-130 and 9.9...9 x 10125 (38 nines followed by 88 zeroes) with 38 digits of precision. If you specify an arithmetic expression whose value has a magnitude greater than or equal to 1.0 x 10126, Oracle returns an error.
Specify a fixed-point number using the following form:
NUMBER(p,s)
where:
s |
is the scale, or the number of digits to the right of the decimal point. The scale can range from -84 to 127. |
Specify an integer using the following form:
|
is a fixed-point number with precision p and scale 0. This is equivalent to NUMBER(p,0). |
Specify a floating-point number using the following form:
|
is a floating-point number with decimal precision 38. Note that a scale value is not applicable for floating-point numbers. (See "Floating-Point Numbers" for more information.) |
Specify the scale and precision of a fixed-point number column for extra integrity checking on input. Specifying scale and precision does not force all values to a fixed length. If a value exceeds the precision, Oracle returns an error. If a value exceeds the scale, Oracle rounds it.
The following examples show how Oracle stores data using different precisions and scales.
If the scale is negative, the actual data is rounded to the specified number of places to the left of the decimal point. For example, a specification of (10,-2) means to round to hundreds.
You can specify a scale that is greater than precision, although it is uncommon. In this case, the precision specifies the maximum number of digits to the right of the decimal point. As with all number datatypes, if the value exceeds the precision, Oracle returns an error message. If the value exceeds the scale, Oracle rounds the value. For example, a column defined as NUMBER(4,5) requires a zero for the first digit after the decimal point and rounds all values past the fifth digit after the decimal point. The following examples show the effects of a scale greater than precision:
Actual Data | Specified As | Stored As |
.01234 |
NUMBER(4,5) |
.01234 |
.00012 |
NUMBER(4,5) |
.00012 |
.000127 |
NUMBER(4,5) |
.00013 |
.0000012 |
NUMBER(2,7) |
.0000012 |
.00000123 |
NUMBER(2,7) |
.0000012 |
Oracle allows you to specify floating-point numbers, which can have a decimal point anywhere from the first to the last digit or can have no decimal point at all. A scale value is not applicable to floating-point numbers, because the number of digits that can appear after the decimal point is not restricted.
You can specify floating-point numbers with the form discussed in "NUMBER Datatype". Oracle also supports the ANSI datatype FLOAT. You can specify this datatype using one of these syntactic forms:
LONG columns store variable length character strings containing up to 2 gigabytes, or 231-1 bytes. LONG columns have many of the characteristics of VARCHAR2 columns. You can use LONG columns to store long text strings. Oracle uses LONG columns in the data dictionary to store the text of view definitions. The length of LONG values may be limited by the memory available on your computer.
You can reference LONG columns in SQL statements in these places:
The use of LONG values are subject to some restrictions:
LONG columns cannot appear in certain parts of SQL statements:
Triggers can use the LONG datatype in the following manner:
You can use the Oracle Call Interface functions to retrieve a portion of a LONG value from the database. See Oracle Call Interface Programmer's Guide.
The DATE datatype stores date and time information. Although date and time information can be represented in both CHAR and NUMBER datatypes, the DATE datatype has special associated properties. For each DATE value, Oracle stores the following information: century, year, month, day, hour, minute, and second.
To specify a date value, you must convert a character or numeric value to a date value with the TO_DATE function. Oracle automatically converts character values that are in the default date format into date values when they are used in date expressions. The default date format is specified by the initialization parameter NLS_DATE_FORMAT and is a string such as 'DD-MON-YY'. This example date format includes a two-digit number for the day of the month, an abbreviation of the month name, and the last two digits of the year.
If you specify a date value without a time component, the default time is 12:00:00 am (midnight). If you specify a date value without a date, the default date is the first day of the current month.
The date function SYSDATE returns the current date and time. For information on the SYSDATE and TO_DATE functions and the default date format, see Chapter 3, "Operators, Functions, Expressions, Conditions".
You can add and subtract number constants as well as other dates from dates. Oracle interprets number constants in arithmetic date expressions as numbers of days. For example, SYSDATE + 1 is tomorrow. SYSDATE - 7 is one week ago. SYSDATE + (10/1440) is ten minutes from now. Subtracting the HIREDATE column of the EMP table from SYSDATE returns the number of days since each employee was hired. You cannot multiply or divide DATE values.
Oracle provides functions for many of the common date operations. For example, the ADD_MONTHS function allows you to add or subtract months from a date. The MONTHS_BETWEEN function returns the number of months between two dates. The fractional portion of the result represents that portion of a 31-day month. For more information on date functions, see "Date Functions".
Because each date contains a time component, most results of date operations include a fraction. This fraction means a portion of one day. For example, 1.5 days is 36 hours.
A Julian date is the number of days since January 1, 4712 bc. Julian dates allow continuous dating from a common reference. You can use the date format model "J" with date functions TO_DATE and TO_CHAR to convert between Oracle DATE values and their Julian equivalents.
This statement returns the Julian equivalent of January 1, 1997:
SELECT TO_CHAR(TO_DATE('01-01-1997', 'MM-DD-YYYY'),'J') FROM DUAL; TO_CHAR -------- 2450450
For a description of the DUAL table, see "Selecting from the DUAL Table".
The RAW and LONG RAW datatypes store data that is not to be interpreted (not explicitly converted when moving data between different systems) by Oracle. These datatypes are intended for binary data or byte strings. For example, you can use LONG RAW to store graphics, sound, documents, or arrays of binary data; the interpretation is dependent on the use.
RAW is a variable-length datatype like the VARCHAR2 character datatype, except that Net8 (which connects user sessions to the instance) and the Import and Export utilities do not perform character conversion when transmitting RAW or LONG RAW data. In contrast, Net8 and Import/Export automatically convert CHAR, VARCHAR2, and LONG data from the database character set to the user session character set (set by the NLS_LANGUAGE parameter of the ALTER SESSION command), if the two character sets are different.
When Oracle automatically converts RAW or LONG RAW data to and from CHAR data, the binary data is represented in hexadecimal form with one hexadecimal character representing every four bits of RAW data. For example, one byte of RAW data with bits 11001011 is displayed and entered as 'CB'.
You can index RAW data, but not LONG RAW data.
Internal LOB datatypes-BLOB, CLOB, NCLOB-and external datatype BFILE, can store large and unstructured data such as text, image, video, and spatial data up to 4 gigabytes in size.
When creating a table, you can optionally specify different tablespace and storage characteristics for internal LOB columns or internal LOB object attributes from those specified for the table.
Internal LOB columns contain LOB locators that can refer to out-of-line or in-line LOB values. Selecting a LOB from a table actually returns the LOB's locator and not the entire LOB value. The DBMS_LOB package and OCI operations on LOBs are performed through these locators. For more information about these interfaces and LOBs, see Oracle8 Application Developer's Guide and Oracle Call Interface Programmer's Guide.
LOBs are similar to LONG and LONG RAW types, but differ in the following ways:
For more information, please refer to the discussion of LOB restrictions in Oracle8 Application Developer's Guide.
To access and populate rows of an internal LOB column, use the INSERT statement first to initialize the internal LOB value to empty. Once the row is inserted, you can select the empty LOB and populate it using the DBMS_LOB package or the OCI.
The following example creates a table with LOB columns:
CREATE TABLE person_table (name CHAR(40), resume CLOB, picture BLOB) LOB (resume) STORE AS ( TABLESPACE resumes STORAGE (INITIAL 5M NEXT 5M) );
Use LOBs to read and write large chunks of the LOB value.
The BFILE datatype enables access to binary file LOBs that are stored in file systems outside the Oracle database. A BFILE column or attribute stores a BFILE locator, which serves as a pointer to a binary file on the server's file system. The locator maintains the directory alias and the filename. See CREATE DIRECTORY.
Binary file LOBs do not participate in transactions. Rather, the underlying operating system provides file integrity and durability. The maximum file size supported is 4 gigabytes.
The database administrator must ensure that the file exists and that Oracle processes have operating system read permissions on the file.
The BFILE datatype allows read-only support of large binary files; you cannot modify a file. Oracle provides APIs to access file data. The primary interfaces that you use to access file data are the DBMS_LOB package and the OCI. For more information about LOBs, see Oracle8 Application Developer's Guide and Oracle Call Interface Programmer's Guide.
The BLOB datatype stores unstructured binary large objects. BLOBs can be thought of as bitstreams with no character set semantics. BLOBs can store up to 4 gigabytes of binary data.
BLOBs have full transactional support; changes made through SQL, the DBMS_LOB package, or the OCI participate fully in the transaction. The BLOB value manipulations can be committed or rolled back. Note, however, that you cannot save a BLOB locator in a PL/SQL or OCI variable in one transaction and then use it in another transaction or session.
The CLOB datatype stores single-byte character large object data. Variable-width character sets are not supported. CLOBs can store up to 4 gigabytes of character data.
CLOBs have full transactional support; changes made through SQL, the OCI, or the DBMS_LOB package participate fully in the transaction. The CLOB value manipulations can be committed or rolled back. Note, however, that, you cannot save a CLOB locator in a PL/SQL or OCI variable in one transaction and then use it in another transaction or session.
The NCLOB datatype stores fixed-width, multibyte national character set character (NCHAR) data. Variable-width character sets are not supported. NCLOBs can store up to 4 gigabytes of character text data.
NCLOBs have full transactional support; changes made through SQL, the DBMS_LOB package, or the OCI participate fully in the transaction. NCLOB value manipulations can be committed or rolled back. Note, however, that you cannot save a NCLOB locator in a PL/SQL or OCI variable in one transaction and then use it in another transaction or session.
You cannot create an object with NCLOB attributes, but you can specify NCLOB parameters in methods.
Each row in the database has an address. You can examine a row's address by querying the pseudocolumn ROWID. Values of this pseudocolumn are hexadecimal strings representing the address of each row. These strings have the datatype ROWID. For more information on the ROWID pseudocolumn, see "Pseudocolumns". You can also create tables and clusters that contain actual columns having the ROWID datatype. Oracle does not guarantee that the values of such columns are valid ROWIDs.
Oracle8 incorporates an extended format for ROWIDs to efficiently support partitioned tables and indexes and tablespace-relative data block addresses (DBAs) without ambiguity.
Character values representing ROWIDs in Oracle7 and earlier releases are as follows:
block.row.file
where:
In Oracle8, this kind of ROWID is called a restricted ROWID.
The Oracle8 extended ROWID datatype stored in a user column includes the data in the restricted ROWID plus a data object number. The data object number is an identification number assigned to every database segment. You can retrieve the data object number from data dictionary views USER_OBJECTS, DBA_OBJECTS, and ALL_OBJECTS. Objects that share the same segment (clustered tables in the same cluster, for example) have the same object number.
Extended ROWIDs are not available directly. You can use a supplied package, DBMS_ROWID, to interpret extended ROWID contents. The package functions extract and provide information that would be available directly from a restricted ROWID. You can use functions from the DBMS_ROWID package as you would any built-in SQL function. Table 2-2 lists the functions and procedures in the DBMS_ROWID package. For more information on DBMS_ROWID, see Oracle8 Application Developer's Guide.
The restricted form of ROWID is still supported in Oracle8 for backward compatibility, but all tables return ROWIDs in the extended format. For information regarding compatibility and migration issues, see Oracle8 Migration.
The MLSLABEL datatype stores the binary format of a label used on a secure operating system. This datatype is supported in Oracle8 for backward compatibility with earlier versions of Oracle servers using Trusted Oracle.
Labels are used by Trusted Oracle to mediate access to information. You can also define columns with this datatype if you are using the standard Oracle server. For more information on Trusted Oracle, including this datatype and labels, see your Trusted Oracle documentation.
SQL commands that create tables and clusters can also use ANSI datatypes and datatypes from IBM's products SQL/DS and DB2. Oracle recognizes the ANSI or IBM datatype name and records it as the name of the datatype of the column, and then stores the column's data in an Oracle datatype based on the conversions shown in Table 2-3 and Table 2-4.
Do not define columns with these SQL/DS and DB2 datatypes, because they have no corresponding Oracle datatype:
Note that data of type TIME and TIMESTAMP can also be expressed as Oracle DATE data.
User-defined datatypes use Oracle built-in datatypes and other user-defined datatypes as the building blocks of types that model the structure and behavior of data in applications. For information about Oracle built-in datatypes, see Oracle8 Concepts. For information about creating user-defined types, see CREATE TYPE and the CREATE TYPE BODY. For information about using user-defined types, see Oracle8 Application Developer's Guide.
Object types are abstractions of the real-world entities-for example, purchase orders-that application programs deal with. An object type is a schema object with three kinds of components:
An object identifier (OID) uniquely identifies an object and enables you to reference the object from other objects or from relational tables. A built-in datatype called REF represents such references. A REF is a container for an object identifier. REFs are pointers to objects.
When a REF value points to a nonexistent object, the REF is said to be DANGLING. DANGLING is different from being NULL. To check to see if a REF is dangling or not, use the predicate IS [NOT] DANGLING. For example, given table DEPT with column MGR whose type is a REF to type EMP_T:
SELECT t.mgr.name FROM dept t WHERE t.mgr IS NOT DANGLING;
An array is an ordered set of data elements. All elements of a given array are of the same datatype. Each element has an index, which is a number corresponding to the element's position in the array.
The number of elements in an array is the size of the array. Oracle arrays are of variable size, which is why they are called VARRAYs. You must specify a maximum size when you declare the array.
When you declare a VARRAY, it does not allocate space. It defines a type, which you can use as
An array object may be stored in line (that is, in the same tablespace as the other data in its row) or out of line, depending on its size.
A nested table type is used to model an unordered set of elements. The elements may be built-in types or user-defined types. You can view a nested table as a single-column table or, if the nested table is an object type, as a multicolumn table, with a column for each attribute of the object type.
A nested table definition does not allocate space. It defines a type, which you can use to declare
When a nested table appears as the type of a column in a relational table or as an attribute of the underlying object type of an object table, Oracle stores all of the nested table data in a single table, which it associates with the enclosing relational or object table.
This section describes how Oracle compares values of each datatype.
A larger value is considered greater than a smaller one. All negative numbers are less than zero and all positive numbers. Thus, -1 is less than 100; -100 is less than -1.
A later date is considered greater than an earlier one. For example, the date equivalent of '29-MAR-1991' is less than that of '05-JAN-1992' and '05-JAN-1992 1:35pm' is greater than '05-JAN-1992 10:09am'.
Character values are compared using one of these comparison rules:
The following sections explain these comparison semantics. The results of comparing two character values using different comparison semantics may be different. Table 2-5 shows the results of comparing five pairs of character values using each comparison semantic. Usually, the results of blank-padded and nonpadded comparisons are the same.The last comparison in the table illustrates the differences between the blank-padded and nonpadded comparison semantics.
Blank-Padded | Nonpadded |
---|---|
|
|
|
|
|
|
|
|
'a ' = 'a' |
'a ' > 'a' |
If the two values have different lengths, Oracle first adds blanks to the end of the shorter one so their lengths are equal. Oracle then compares the values character by character up to the first character that differs. The value with the greater character in the first differing position is considered greater. If two values have no differing characters, then they are considered equal. This rule means that two values are equal if they differ only in the number of trailing blanks. Oracle uses blank-padded comparison semantics only when both values in the comparison are either expressions of datatype CHAR, NCHAR, text literals, or values returned by the USER function.
Oracle compares two values character by character up to the first character that differs. The value with the greater character in that position is considered greater. If two values of different length are identical up to the end of the shorter one, the longer value is considered greater. If two values of equal length have no differing characters, then the values are considered equal. Oracle uses nonpadded comparison semantics whenever one or both values in the comparison have the datatype VARCHAR2 or NVARCHAR2.
Oracle compares single characters according to their numeric values in the database character set. One character is greater than another if it has a greater numeric value than the other in the character set. Oracle considers blanks to be less than any character, which is true in most character sets.
These are some common character sets:
Portions of the ASCII and EBCDIC character sets appear in Table 2-6 and Table 2-7. Note that uppercase and lowercase letters are not equivalent. Also, note that the numeric values for the characters of a character set may not match the linguistic sequence for a particular language.
Object values are compared using one of two comparison functions: MAP and ORDER. Both functions compare object type instances, but they are quite different from one another. These functions must be specified as part of the object type.
A MAP function takes a single object as an argument and returns a scalar value. To compare two objects, the MAP method is applied to each of the objects individually. Then the results are compared. MAP is like a hash function that maps object types into scalars.
An ORDER function takes two objects (object1 and object2, for example) and simply compares one object value to the other. ORDER returns the result +1 if object1 is greater than object2, 0 if equal to, or -1 if less than. Order methods cannot return a NULL value.
Use MAP if you are performing extensive sorting or hash join operations on object instances. MAP is applied once to map the objects to scalar values and then the scalars are used during sorting and merging. A MAP method is more efficient than an ORDER method, which must invoke the method for each object comparison. You must use a MAP method for hash joins and cannot use an ORDER method because the hash mechanism hashes on the object value.
An object specification can contain only one comparison method, which must be a function. You can define either MAP method or ORDER method in a type specification, but not both.
No comparison method needs to be specified to determine the equality of two object types.
See CREATE TYPE and the Oracle8 Application Developer's Guide for more information.
You cannot compare VARRAYs and nested tables in Oracle8.
Generally an expression cannot contain values of different datatypes. For example, an expression cannot multiply 5 by 10 and then add 'JAMES'. However, Oracle supports both implicit and explicit conversion of values from one datatype to another.
Oracle automatically converts a value from one datatype to another when such a conversion makes sense. Oracle performs conversions in these cases:
The text literal '10' has datatype CHAR. Oracle implicitly converts it to the NUMBER datatype if it appears in a numeric expression as in the following statement:
SELECT sal + '10' FROM emp;
When a condition compares a character value and a NUMBER value, Oracle implicitly converts the character value to a NUMBER value, rather than converting the NUMBER value to a character value. In the following statement, Oracle implicitly converts '7936' to 7936:
SELECT ename FROM emp WHERE empno = '7936';
In the following statement, Oracle implicitly converts '12-MAR-1993' to a DATE value using the default date format 'DD-MON-YYYY':
SELECT ename FROM emp WHERE hiredate = '12-MAR-1993';
In the following statement, Oracle implicitly converts the text literal 'AAAAZ8AABAAABvlAAA' to a ROWID value:
SELECT ename FROM emp WHERE ROWID = 'AAAAZ8AABAAABvlAAA';
You can also explicitly specify datatype conversions using SQL conversion functions. Table 2-8 shows SQL functions that explicitly convert a value from one datatype to another.
TO: FROM: | CHAR | NUMBER | DATE | RAW | ROWID |
---|---|---|---|---|---|
CHAR |
|
|
|
|
|
NUMBER |
|
|
|
|
|
DATE |
|
|
|
|
|
RAW |
|
|
|
|
|
ROWID |
|
|
|
|
|
For information on these functions, see "Conversion Functions".
Note: Table 2-8 does not show conversions from LONG and LONG RAW values because it is impossible to specify LONG and LONG RAW values in cases in which Oracle can perform implicit datatype conversion. For example, LONG and LONG RAW values cannot appear in expressions with functions or operators. For information on the limitations on LONG and LONG RAW datatypes, see "LONG Datatype". |
Oracle recommends that you specify explicit conversions rather than rely on implicit or automatic conversions for these reasons:
If a column in a row has no value, then column is said to be null, or to contain a null. Nulls can appear in columns of any datatype that are not restricted by NOT NULL or PRIMARY KEY integrity constraints. Use a null when the actual value is not known or when a value would not be meaningful.
Do not use null to represent a value of zero, because they are not equivalent. (Oracle currently treats a character value with a length of zero as null. However, this may not continue to be true in future releases, and Oracle recommends that you do not treat empty strings the same as NULLs.) Any arithmetic expression containing a null always evaluates to null. For example, null added to 10 is null. In fact, all operators (except concatenation) return null when given a null operand.
All scalar functions (except NVL and TRANSLATE) return null when given a null argument. The NVL function can be used to return a value when a null occurs. For example, the expression NVL(COMM,0) returns 0 if COMM is null or the value of COMM if it is not null.
Most group functions ignore nulls. For example, consider a query that averages the five values 1000, null, null, null, and 2000. Such a query ignores the nulls and calculates the average to be (1000+2000)/2 = 1500.
To test for nulls, use only the comparison operators IS NULL and IS NOT NULL. If you use any other operator with nulls and the result depends on the value of the null, the result is UNKNOWN. Because null represents a lack of data, a null cannot be equal or unequal to any value or to another null. However, note that Oracle considers two nulls to be equal when evaluating a DECODE expression. For information on the DECODE syntax, see "Expressions".
Oracle also considers two nulls to be equal if they appear in compound keys. That is, Oracle considers identical two compound keys containing nulls if all the non-null components of the keys are equal.
A condition that evaluates to UNKNOWN acts almost like FALSE. For example, a SELECT statement with a condition in the WHERE clause that evaluates to UNKNOWN returns no rows. However, a condition evaluating to UNKNOWN differs from FALSE in that further operations on an UNKNOWN condition evaluation will evaluate to UNKNOWN. Thus, NOT FALSE evaluates to TRUE, but NOT UNKNOWN evaluates to UNKNOWN.
Table 2-9 shows examples of various evaluations involving nulls in conditions. If the conditions evaluating to UNKNOWN were used in a WHERE clause of a SELECT statement, then no rows would be returned for that query.
For the truth tables showing the results of logical expressions containing nulls, see Table 3-6, as well as Table 3-7 and Table 3-8.
A pseudocolumn behaves like a table column, but is not actually stored in the table. You can select from pseudocolumns, but you cannot insert, update, or delete their values. This section describes these pseudocolumns:
A sequence is a schema object that can generate unique sequential values. These values are often used for primary and unique keys. You can refer to sequence values in SQL statements with these pseudocolumns:
CURRVAL |
returns the current value of a sequence. |
NEXTVAL |
increments the sequence and returns the next value. |
You must qualify CURRVAL and NEXTVAL with the name of the sequence:
sequence.CURRVAL sequence.NEXTVAL
To refer to the current or next value of a sequence in the schema of another user, you must have been granted either SELECT object privilege on the sequence or SELECT ANY SEQUENCE system privilege, and you must qualify the sequence with the schema containing it:
schema.sequence.CURRVAL schema.sequence.NEXTVAL
To refer to the value of a sequence on a remote database, you must qualify the sequence with a complete or partial name of a database link:
schema.sequence.CURRVAL@dblink schema.sequence.NEXTVAL@dblink
For more information on referring to database links, see "Referring to Objects in Remote Databases".
If you are using Trusted Oracle in DBMS MAC mode, you can refer to a sequence only if your DBMS label dominates the sequence's creation label or if one of these criteria is satisfied:
If you are using Trusted Oracle in OS MAC mode, you cannot refer to a sequence with a lower creation label than your DBMS label.
You can use CURRVAL and NEXTVAL in these places:
You cannot use CURRVAL and NEXTVAL in these places:
Also, within a single SQL statement that uses CURVAL or NEXTVAL, all referenced LONG columns, updated tables, and locked tables must be located on the same database.
When you create a sequence, you can define its initial value and the increment between its values. The first reference to NEXTVAL returns the sequence's initial value. Subsequent references to NEXTVAL increment the sequence value by the defined increment and return the new value. Any reference to CURRVAL always returns the sequence's current value, which is the value returned by the last reference to NEXTVAL. Note that before you use CURRVAL for a sequence in your session, you must first initialize the sequence with NEXTVAL.
Within a single SQL statement, Oracle will increment the sequence only once. If a statement contains more than one reference to NEXTVAL for a sequence, Oracle increments the sequence once and returns the same value for all occurrences of NEXTVAL. If a statement contains references to both CURRVAL and NEXTVAL, Oracle increments the sequence and returns the same value for both CURRVAL and NEXTVAL regardless of their order within the statement.
A sequence can be accessed by many users concurrently with no waiting or locking. For information on sequences, see CREATE SEQUENCE.
This example selects the current value of the employee sequence:
SELECT empseq.currval FROM DUAL;
This example increments the employee sequence and uses its value for a new employee inserted into the employee table:
INSERT INTO emp VALUES (empseq.nextval, 'LEWIS', 'CLERK', 7902, SYSDATE, 1200, NULL, 20);
This example adds a new order with the next order number to the master order table. It then adds suborders with this number to the detail order table:
INSERT INTO master_order(orderno, customer, orderdate) VALUES (orderseq.nextval, 'Al''s Auto Shop', SYSDATE); INSERT INTO detail_order (orderno, part, quantity) VALUES (orderseq.currval, 'SPARKPLUG', 4); INSERT INTO detail_order (orderno, part, quantity) VALUES (orderseq.currval, 'FUEL PUMP', 1); INSERT INTO detail_order (orderno, part, quantity) VALUES (orderseq.currval, 'TAILPIPE', 2);
For each row returned by a hierarchical query, the LEVEL pseudocolumn returns 1 for a root node, 2 for a child of a root, and so on. A root node is the highest node within an inverted tree. A child node is any nonroot node. A parent node is any node that has children. A leaf node is any node without children. Figure 2-1 shows the nodes of an inverted tree with their LEVEL values.
To define a hierarchical relationship in a query, you must use the START WITH and CONNECT BY clauses. For more information on using the LEVEL pseudocolumn, see SELECT.
For each row in the database, the ROWID pseudocolumn returns a row's address. Oracle8 ROWID values contain information necessary to locate a row:
Usually, a ROWID value uniquely identifies a row in the database. However, rows in different tables that are stored together in the same cluster can have the same ROWID.
Values of the ROWID pseudocolumn have the datatype ROWID. For information on the ROWID datatype, see "ROWID Datatype".
ROWID values have several important uses:
You should not use ROWID as a table's primary key. If you delete and reinsert a row with the Import and Export utilities, for example, its ROWID may change. If you delete a row, Oracle may reassign its ROWID to a new row inserted later.
Although you can use the ROWID pseudocolumn in the SELECT and WHERE clauses of a query, these pseudocolumn values are not actually stored in the database. You cannot insert, update, or delete a value of the ROWID pseudocolumn.
This statement selects the address of all rows that contain data for employees in department 20:
SELECT ROWID, ename FROM emp WHERE deptno = 20; ROWID ENAME ------------------ ---------- AAAAfSAABAAAClaAAA SMITH AAAAfSAABAAAClaAAD JONES AAAAfSAABAAAClaAAH SCOTT AAAAfSAABAAAClaAAK ADAMS AAAAfSAABAAAClaAAM FORD
For each row returned by a query, the ROWNUM pseudocolumn returns a number indicating the order in which Oracle selects the row from a table or set of joined rows. The first row selected has a ROWNUM of 1, the second has 2, and so on.
You can use ROWNUM to limit the number of rows returned by a query, as in this example:
SELECT * FROM emp WHERE ROWNUM < 10;
Note that conditions testing for ROWNUM values greater than a positive integer are always false. For example, this query returns no rows:
SELECT * FROM emp WHERE ROWNUM > 1;
The first row fetched is assigned a ROWNUM of 1 and makes the condition false. The second row to be fetched is now the first row and is also assigned a ROWNUM of 1 and makes the condition false. All rows subsequently fail to satisfy the condition, so no rows are returned.
You can also use ROWNUM to assign unique values to each row of a table, as in this example:
UPDATE tabx SET col1 = ROWNUM;
Oracle assigns a ROWNUM value to each row as it is retrieved, before rows are sorted for an ORDER BY clause, so an ORDER BY clause normally does not affect the ROWNUM of each row. However, if an ORDER BY clause causes Oracle to use an index to access the data, Oracle may retrieve the rows in a different order than without the index, so the ROWNUMs may be different than they would be without the ORDER BY clause.
Note: Using ROWNUM in a query can affect view optimization. For more information, see Oracle8 Concepts. |
You can associate comments with SQL statements and schema objects.
Comments within SQL statements do not affect the statement execution, but they may make your application easier for you to read and maintain. You may want to include a comment in a statement that describes the statement's purpose within your application.
A comment can appear between any keywords, parameters, or punctuation marks in a statement. You can include a comment in a statement using either of these means:
A SQL statement can contain multiple comments of both styles. The text of a comment can contain any printable characters in your database character set.
Note: You cannot use these styles of comments between SQL statements in a SQL script. Use the Server Manager or SQL*Plus REMARK command for this purpose. For information on these commands, see Oracle Server Manager User's Guide or SQL*Plus User's Guide and Reference. |
These statements contain many comments:
SELECT ename, sal + NVL(comm, 0), job, loc /* Select all employees whose compensation is greater than that of Jones.*/ FROM emp, dept /*The DEPT table is used to get the department name.*/ WHERE emp.deptno = dept.deptno AND sal + NVL(comm,0) > /* Subquery: */ (SELECT sal + NLV(comm,0) /* total compensation is sal + comm */ FROM emp WHERE ename = 'JONES') SELECT ename, -- select the name sal + NVL(comm, 0), -- total compensation job, -- job loc -- and city containing the office FROM emp, -- of all employees dept WHERE emp.deptno = dept.deptno AND sal + NVL(comm, 0) > -- whose compensation -- is greater than (SELECT sal + NVL(comm,0) -- the compensation FROM emp WHERE ename = 'JONES') -- of Jones.
You can associate a comment with a table, view, snapshot, or column using the COMMENT command described in Chapter 4, "Commands". Comments associated with schema objects are stored in the data dictionary.
You can use comments in a SQL statement to pass instructions, or hints, to the Oracle optimizer. The optimizer uses these hints to choose an execution plan for the statement.
A statement block can have only one comment containing hints, and that comment must follow the SELECT, UPDATE, INSERT, or DELETE keyword. The syntax below shows the syntax for hints contained in both styles of comments that Oracle supports within a statement block.
{DELETE|INSERT|SELECT|UPDATE} /*+ hint [text] [hint[text]]... */
or
{DELETE|INSERT|SELECT|UPDATE} --+ hint [text] [hint[text]]...
where:
UPDATE |
is a DELETE, INSERT, SELECT, or UPDATE keyword that begins a statement block. Comments containing hints can appear only after these keywords. |
+ |
is a plus sign that causes Oracle to interpret the comment as a list of hints. The plus sign must follow immediately after the comment delimiter (no space is permitted). |
hint |
is one of the hints discussed in this section and in Oracle8 Tuning. The space between the plus sign and the hint is optional. If the comment contains multiple hints, each pair of hints must be separated by at least one space. |
text |
is other commenting text that can be interspersed with the hints. |
Table 2-10 lists hint syntax and descriptions. For more information on hints, see Oracle8 Tuning, Oracle8 Parallel Server Concepts and Administration, and Oracle8 Concepts.
A schema is a collection of logical structures of data, or schema objects. A schema is owned by a database user and has the same name as that user. Each user owns a single schema. Schema objects can be created and manipulated with SQL and include the following types of objects:
In addition, the following schema objects are available if you are using Oracle's distributed functionality:
In addition, the following schema objects are available if the objects option is installed on your database server:
Other types of objects are also stored in the database and can be created and manipulated with SQL but are not contained in a schema:
In this reference, each type of object is briefly defined in Chapter 4, "Commands", in the section describing the command that creates the database object. These commands begin with the keyword CREATE. For example, for the definition of a cluster, see CREATE CLUSTER. For an overview of database objects, see Oracle8 Concepts.
You must provide names for most types of schema objects when you create them. These names must follow the rules listed in the following sections.
Some schema objects are made up of parts that you must name, such as:
Tables and indexes can be partitioned. When partitioned, these schema objects consist of a number of parts called partitions, all of which have the same logical attributes. For example, all partitions in a table share the same column and constraint definitions, and all partitions in an index share the same index columns.
Partitions can be used as tables. This capability provides you with a shortcut for performing some partition-level operations that would otherwise require using a WHERE clause.
To use a partition as a table, create a view by selecting data from a single partition, and then use the view as a table. The advantage of this method is that you can build partition-level access control mechanisms by granting (or revoking) privileges on these views to (or from) other users or roles.
Partition-level bulk operations, such as deleting all of the rows from a partition, restrict the operation to one partition. These types of operations are easily expressed with the partition-extended table name syntax. Trying to phrase the same operation with a WHERE clause predicate can be cumbersome, especially when the range partitioning key uses more than one column.
Table specification syntax has been extended for the following DML statements to allow an optional partition specification for nonremote partitioned tables:
Currently, the use of partition-extended table names has the following restrictions:
The basic syntax for using partition-extended table names is:
[schema.]{table | view} [@dblink | PARTITION (partition_name)]
In the following statement, SALES is a partitioned table with partition JAN97. You can create a view of the single partition JAN97, and then use it as if it were a table. This example deletes rows from the partition.
CREATE VIEW sales_jan97 AS SELECT * FROM sales PARTITION (jan97); DELETE FROM sales_jan97 WHERE amount < 0;
This section provides:
The following rules apply when naming schema objects:
If your database character set contains multibyte characters, Oracle recommends that each name for a user or a role contain at least one single-byte character.
Depending on the Oracle product you plan to use to access a database object, names might be further restricted by other product-specific reserved words. For a list of a product's reserved words, see the manual for the specific product, such as PL/SQL User's Guide and Reference.
Appendix C, "Oracle Reserved Words and Keywords" lists Oracle keywords.
Figure 2-2 shows the namespaces for schema objects; each box is a namespace. Tables and views are in the same namespace; therefore, a table and a view in the same schema cannot have the same name. However, tables and indexes are in different namespaces; therefore, a table and an index in the same schema can have the same name.
Each schema in the database has its own namespaces for the objects it contains. This means, for example, that two tables in different schemas are in different namespaces and can have the same name.
Figure 2-3 shows the namespaces for nonschema objects. Because the objects in these namespaces are not contained in schemas, these namespaces span the entire database.
If you give a schema object a name enclosed in double quotation marks, you must use double quotation marks whenever you refer to the object.
Enclosing a name in double quotes allows it to
By enclosing names in double quotation marks, you can give the following names to different objects in the same namespace:
emp "emp" "Emp" "EMP "
Note that Oracle interprets the following names the same, so they cannot be used for different objects in the same namespace:
emp EMP "EMP"
If you give a user or password a quoted name, the name cannot contain lowercase letters.
Database link names cannot be quoted.
The following examples are valid schema object names:
ename horse scott.hiredate "EVEN THIS & THAT!" a_very_long_and_valid_name
Although column aliases, table aliases, usernames, and passwords are not objects or parts of objects, they must also follow these naming rules with these exceptions:
Here are several helpful guidelines for naming objects and their parts:
When naming objects, balance the objective of keeping names short and easy to use with the objective of making names as descriptive as possible. When in doubt, choose the more descriptive name, because the objects in the database may be used by many people over a period of time. Your counterpart ten years from now may have difficulty understanding a database with a name like PMDD instead of PAYMENT_DUE_DATE.
Using consistent naming rules helps users understand the part that each table plays in your application. One such rule might be to begin the names of all tables belonging to the FINANCE application with FIN_.
Use the same names to describe the same things across tables. For example, the department number columns of the sample EMP and DEPT tables are both named DEPTNO.
This section tells you how to refer to schema objects and their parts in the context of a SQL statement. This section shows you:
The following diagram shows the general syntax for referring to an object or a part:
where:
object |
is the name of the object. |
schema |
is the schema containing the object. The schema qualifier allows you to refer to an object in a schema other than your own. Note that you must be granted privileges to refer to objects in other schemas. If you omit schema, Oracle assumes that you are referring to an object in your own schema. |
|
Only schema objects can be qualified with schema. Schema objects are shown in Figure 2-2. Nonschema objects, shown in Figure 2-3, cannot be qualified with schema because they are not schema objects. (An exception is public synonyms, which can optionally be qualified with "PUBLIC". The quotation marks are required.) |
part |
is a part of the object. This identifier allows you to refer to a part of a schema object, such as a column or a partition of a table. Note that not all types of objects have parts. |
dblink |
applies only when you are using Oracle's distributed functionality. This is the name of the database containing the object. The dblink qualifier allows you to refer to an object in a database other than your local database. If you omit dblink, Oracle assumes that you are referring to an object in your local database. Note that not all SQL statements allow you to access objects on remote databases. |
You can include spaces around the periods separating the components of the reference to the object, but it is conventional to omit them.
When you refer to an object in a SQL statement, Oracle considers the context of the SQL statement and locates the object in the appropriate namespace. After locating the object, Oracle performs the statement's operation on the object. If the named object cannot be found in the appropriate namespace, Oracle returns an error message.
The following example illustrates how Oracle resolves references to objects within SQL statements. Consider this statement that adds a row of data to a table identified by the name DEPT:
INSERT INTO dept VALUES (50, 'SUPPORT', 'PARIS');
Based on the context of the statement, Oracle determines that DEPT can be:
Oracle always attempts to resolve an object reference within the namespaces in your own schema before considering namespaces outside your schema. In this example, Oracle attempts to resolve the name DEPT as follows:
To refer to objects in schemas other than your own, prefix the object name with the schema name:
schema.object
For example, this statement drops the EMP table in the schema SCOTT:
DROP TABLE scott.emp
To refer to objects in databases other than your local database, follow the object name with the name of the database link to that database. A database link is a schema object that causes Oracle to connect to a remote database to access an object there. This section tells you:
You create a database link with the CREATE DATABASE LINK command described in Chapter 4, "Commands". The command allows you to specify this information about the database link:
Oracle stores this information in the data dictionary.
When you create a database link, you must specify its name. The name of a database link can be as long as 128 bytes and can contain periods (.) and the "at" sign (@). In these ways, database link names are different from names of other types of objects.
The name that you give to a database link must correspond to the name of the database to which the database link refers and the location of that database in the hierarchy of database names. The following syntax diagram shows the form of the name of a database link:
dblink::=
where:
The combination database.domain is sometimes called the "service name". For more information, see Net8 Administrator's Guide.
Oracle uses the username and password to connect to the remote database. The username and password for a database link are optional.
The database connect string is the specification used by Net8 to access the remote database. For information on writing database connect strings, see the Net8 documentation for your specific network protocol. The database string for a database link is optional.
Database links are available only if you are using Oracle's distributed functionality. When you issue a SQL statement that contains a database link, you can specify the database link name in one of these forms:
Oracle performs these tasks before connecting to the remote database:
If both of these conditions are true, Oracle proceeds with the connection, using the username and password chosen in Step 2. If not, Oracle returns an error message.
You can enable and disable Oracle resolution of names for remote objects using the initialization parameter GLOBAL_NAMES or the GLOBAL_NAMES parameter of the ALTER SYSTEM or ALTER SESSION command.
For more information on remote name resolution, see Oracle8 Distributed Database Systems.
To reference object type attributes or methods in a SQL statement, you must fully qualify the reference with a table alias. For example, consider the following example:
CREATE TYPE person AS OBJECT (ssno VARCHAR(20), name VARCHAR (10)); CREATE TABLE emptab (pinfo person);
In a SQL statement, reference to the SSNO attribute must be fully qualified using a table alias, as illustrated below:
SELECT e.pinfo.ssno FROM emptab e; UPDATE emptab e SET e.pinfo.ssno = '510129980' WHERE e.pinfo.name = 'Mike';
To reference an object type's member method that does not accept any arguments, you must provide "empty" parentheses. For example, assume that AGE is a method in the person type that does not take any arguments. In order to call this method in a SQL statement, you must provide empty parentheses as shows in this example:
SELECT e.pinfo.age() FROM emptab e WHERE e.pinfo.name = 'Mike';
For more information, see the sections on user-defined datatypes in Oracle8 Concepts.