Oracle9i Lite SQL Reference Release 5.0 Part Number A90108-01 |
|
This document discusses SQL commands used by Oracle Lite. Topics include:
The following lists the different types of SQL commands including clauses and pseudocolumns. An explanation of each SQL command, clause, and pseudocolumn is provided in "SQL Commands Overview".
Table 4-1 SQL Commands
Data Definition Language (DDL) Commands |
||
Data Definition Language (DDL) Commands (cont.) |
||
Data Manipulation Language (DML) |
||
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Transaction Control Commands |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Clauses |
|
|
|
|
|
|
|
|
Pseudocolumns |
|
|
|
|
|
|
|
Oracle Lite uses several different types of SQL commands. This section discusses the different types of SQL commands.
Data definition language (DDL) commands enable you to perform the following tasks:
The CREATE, ALTER, and DROP commands require exclusive access to the object being acted upon. For example, an ALTER TABLE command fails if another user has an open transaction on the specified table.
Data manipulation language (DML) commands query and manipulate data in existing schema objects. These commands do not implicitly commit the current transaction.
Transaction control commands manage changes made by DML commands.
Clauses are subsets of commands that modify the command.
Pseudocolumns are values generated from commands that behave like columns of a table, but are not actually stored in the table. Pseudocolumns are supported by Oracle but are not part of SQL-92.
This section lists Oracle Lite SQL commands, clauses, and pseudocolumns in alphabetical order and discusses each. The discussion includes the following:
Changes a sequence in one of the following ways:
The sequence must be in your own schema.
Table 4-2 Arguments Used with the ALTER SEQUENCE Command
This statement sets a new maximum value for the ESEQ sequence:
ALTER SEQUENCE eseq MAXVALUE 1500
Although the ALTER SEQUENCE command is not part of ODBC SQL; ODBC passes the command through to your database.
CREATE SEQUENCE, DROP SEQUENCE
To specify or modify any of the conditions or parameters that affect your connection to the database. Oracle Lite only enables you to use the SET clause of this command to specify or modify the NLS date format. The statement stays in effect until you disconnect from the database.
None.
Table 4-3 Arguments Used with the ALTER SESSION Command
ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY MM DD HH24:MI:SS';
Oracle Lite uses the new default date format:
SELECT TO_CHAR(SYSDATE) Today FROM DUAL; TODAY ------------------- 1997 08 12 14:25:56
Changes the definition of a table in one of the following ways:
The table must be in your own schema. You must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-4 Arguments Used with the ALTER TABLE Command
Argument | Description |
---|---|
schema |
The name of the schema, which is a character string of up to 128 characters. The schema name must be different from any user names since each user name comes with a default schema with the same name. If you create a schema with the same name as a user name, Oracle Lite returns an error. See "CREATE USER" for more information. |
table |
The name of a database table. |
ADD |
Specifies that a column or integrity constraint is added to the database table. |
DROP |
Specifies that a column or integrity constraint is dropped from the database table. |
column |
The name of a database column. |
datatype |
The datatype of the database column. |
DEFAULT |
Specifies a default value expr (expression) for the new column, or a new default expr for an existing column. |
expr |
A valid expression. Expressions are evaluated when ALTER TABLE is executed, not when a row is inserted with a default value. For more information, see "Specifying Expressions". |
column_constraint |
A column integrity constraint. For more information, see . You cannot add a column with a not null constraint to a table that already contains data. |
table_constraint |
A table integrity constraint. For more information, see "CONSTRAINT clause". |
drop_clause |
An integrity constraint to be dropped. For more information, see "DROP clause". |
ATTACH JAVA |
Attaches a Java class or source file to the database table. |
IN |
Indicates that the Java class or source file must be attached in either a database, Java class, or source path. |
DATABASE |
The database in which you attach the Java class or source path. |
DETACH |
Detaches a Java class from the database table. |
CLASS |
Specifies a Java class. |
SOURCE |
Specifies a Java source file. |
cls_or_src_name |
A fully qualified Java class or source file name. |
cls_or_src_path |
The directory containing the specified Java class or source file. |
WITH CONSTRUCTOR ARGS |
Specifies attributes of the class to be used as arguments to the Java constructor. |
col_name_list |
List of columns (attributes) in the database table. |
AND DELETE |
Deletes the Java class from the database. |
class_name |
The name of a fully qualified Java class. |
ENABLE ALL TRIGGERS |
Enables all triggers associated with the table. The triggers are fired whenever their triggering condition is satisfied. To enable a single trigger, use the ENABLE clause of ALTER TRIGGER. See "ALTER TRIGGER". |
DISABLE ALL TRIGGERS |
Disables all triggers associated with the table. A disabled trigger is not fired even if the triggering condition is satisfied. To disable a single trigger, use the DISABLE clause of ALTER TRIGGER. See "ALTER TRIGGER". |
MODIFY |
This specifies a new default for an existing column. Oracle Lite assigns this value to the column if a subsequent INSERT statement omits a value for the column. The datatype of the default value must match the datatype specified for the column. The column must also be long enough to hold the default value. |
modify_column_option |
This modifies the definition of an existing column. Any of the optional parts of the column definition, datatype, default value (literal, USER, or SYSDATE) or column constraint state (NULL, NOT NULL) which are omitted remain unchanged. Existing datatypes can be changed to a new datatype as long as the existing data is such that the data conversion does not produce any conversion errors. Increasing the size of a varchar column whose existing size is greater than 15 characters does not require any data conversion. All other changes require a data conversion step. Each column is converted individually. Each datatype change involves a rewrite of all objects and creation of all dependent indexes. A column undergoing datatype alteration which is part of an index created using the KEY COLUMNS clause, may cause the ALTER TABLE MODIFY command to fail because the index recreation is unable to reestablish the KEY COLUMNS option. An index created using KEY COLUMNS, should be dropped before modifying the column. |
CONSTRAINT |
Modifies the state of an existing constraint. ENABLE specifies that the constraint is applied to all new data in the table. Before a referential integrity constraint can be enabled, its referenced constraint must be enabled. |
ENABLE VALIDATE |
This setting specifies that all existing data complies with the constraint. An enabled validated constraint guarantees that all data is and continues to be valid. If a user places a primary key constraint in ENABLE VALIDATE mode, validation ensures that primary key columns contain no nulls. If VALIDATE or NOVALIDATE are omitted, the default is VALIDATE. |
ENABLE NOVALIDATE |
This setting ensures that all new DML operations on the constrained data comply with the constraint, but does not ensure that existing data in the table complies with the constraint. Enabling a primary key constraint automatically creates a primary index to enforce the constraint. This index is converted to an ordinary index if the primary key constraint is subsequently disabled. If the constraint is subsequently re-enabled, the index is checked for any primary key constraints and if no violations are detected, is restored to primary key status. |
DISABLE VALIDATE |
This setting disables the constraint and converts the index on the primary key constraint to an ordinary index, but keeps the constraint valid. No DML statements are allowed on the table through SQLRT engine but you may be able to perform a DML statement through Oracle Lite Java Access Classes (JAC). If VALIDATE or NOVALIDATE are omitted, the default is NOVALIDATE. |
DISABLE NOVALIDATE |
This setting signifies that Oracle Lite makes no effort to maintain the constraint (because it is disabled) and cannot guarantee that the constraint is true (because it is not validated). A primary key constraint index is downgraded to an ordinary index. You cannot drop a table with a primary key that is referenced by a foreign key even if the foreign key constraint is in the DISABLE NOVALIDATE state. |
If you use the ADD clause to add a new column to the table, then the initial value of each row for the new column is null. You can add a column with a NOT NULL constraint only when a default value is also specified, regardless of whether or not the table is empty.
If VALIDATE or NOVALIDATE are omitted from the ENABLE argument, the default is NOVALIDATE.
If VALIDATE or NOVALIDATE are omitted from the DISABLE argument, the default is NOVALIDATE.
The nullity constrain is the only integrity constraint that can be added to an existing column using the MODIFY clause with the column constraint syntax. NOT NULL can be added only if the column contains no nulls. A NULL can be added provided the column is not a component of a primary key constraint.
The following statement adds the columns THRIFTPLAN and LOANCODE to the EMP table. THRIFTPLAN has a datatype, NUMBER, with a maximum of seven digits and two decimal places. LOANCODE has a datatype, CHAR, with a size of one and a NOT NULL integrity constraint:
ALTER TABLE emp ADD (thriftplan NUMBER(7,2), loancode CHAR(1));
CONSTRAINT clause, CREATE TABLE, CREATE VIEW
To enable or disable a database trigger. For information on creating a trigger, see "CREATE TRIGGER". For information on dropping a trigger, see "DROP TRIGGER".
Note: This statement does not change the declaration or definition of an existing trigger. To redeclare or redefine a trigger, use the CREATE TRIGGER statement with OR REPLACE. |
To alter a trigger you must have the DBA/DDL privilege.
Table 4-5 Parameters of the ALTER TRIGGER Command
schema |
The schema containing the trigger. If you omit schema, Oracle Lite assumes the trigger is in your own schema. |
trigger |
The name of the trigger to be altered. |
ENABLE |
Enables the trigger. You can also use the ENABLE ALL TRIGGERS clause of ALTER TABLE to enable all triggers associated with a table. See "ALTER TABLE". |
DISABLE |
Disables the trigger. You can also use the DISABLE ALL TRIGGERS clause of ALTER TABLE to disable all triggers associated with a table. See "ALTER TABLE". |
Consider a trigger named REORDER created on the INVENTORY table. The trigger is fired whenever an UPDATE statement reduces the number of a particular part on hand below the part's reorder point. The trigger inserts into a table of pending orders a row that contains the part number, a reorder quantity, and the current date.
When this trigger is created, Oracle Lite enables it automatically. You can subsequently disable the trigger with the following statement:
ALTER TRIGGER reorder DISABLE;
When the trigger is disabled, Oracle Lite does not fire the trigger when an UPDATE statement causes the part's inventory to fall below its reorder point.
After disabling the trigger, you can subsequently enable it with the following statement:
ALTER TRIGGER reorder ENABLE;
After you reenable the trigger, Oracle Lite fires the trigger whenever a part's inventory falls below its reorder point as a result of an UPDATE statement. It is possible that a part's inventory falls below its reorder point while the trigger was disabled. In that case, when you reenable the trigger, Oracle Lite does not automatically fire the trigger for this part until another transaction further reduces the inventory.
Changes a database user's password.
You can change your user password in the database if you meet one of the following conditions:
The following example creates a user named "todd" identified by the password, "tiger". It then changes the user's password to "lion".
CREATE USER todd IDENTIFIED BY tiger; ALTER USER todd IDENTIFIED BY lion;
Recompiles a view.
The view must be in your own schema. You must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-7 Arguments Used with the ALTER VIEW Command
Argument | Description |
---|---|
schema |
The schema to contain the view. If you omit schema, Oracle Lite alters the view in your own schema. |
view |
The name of the view to be recompiled. |
COMPILE |
Causes Oracle Lite to recompile the view. The COMPILE keyword is required. |
You can use ALTER VIEW to explicitly recompile a view that is invalid. Explicit recompilation allows you to locate recompilation errors before run-time. You may want to explicitly recompile a view after altering one of its base tables to ensure that the alteration does not affect the view or other objects that depend on it. When you issue an ALTER VIEW statement, Oracle Lite recompiles the view regardless of whether it is valid or invalid. Oracle Lite also invalidates any local objects that depend on the view.
This command does not change the definition of an existing view. To redefine a view, you must use the CREATE VIEW command with the OR REPLACE option.
The following code demonstrates the ALTER VIEW SQL command. The COMPILE keyword is required.
ALTER VIEW customer_view COMPILE;
Ends your current transaction, making permanent to the database all its changes.
None.
Table 4-8 Arguments Used with the Commit Command
Argument | Description |
---|---|
WORK |
An optional argument with no effect. WORK is supported only for compliance with standard SQL. The statements COMMIT and COMMIT WORK are equivalent. |
Oracle Lite does not autocommit any DDL statements except for CREATE DATABASE. You must commit your current transaction to make permanent all of its changes to the database.
The following code demonstrates the COMMIT command. This example inserts a row into the DEPT table and commits the change. The WORK argument is optional.
INSERT INTO dept VALUES (50, 'Marketing', 'TAMPA'); COMMIT;
Although the COMMIT command is not part of the ODBC SQL syntax, ODBC passes the command through to your database.
An ODBC program typically uses the API call SQLTransact() with the SQL_COMMIT flag.
Defines an integrity constraint.
CONSTRAINT clauses can appear in both the CREATE TABLE and ALTER TABLE commands. To define an integrity constraint, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges. Oracle Lite only has integrity constraints.
Table 4-9 Arguments Used with the Constraint Clause
Argument | Description |
---|---|
CONSTRAINT |
Identifies the integrity constraint named by the constraint argument. Oracle Lite stores the constraint's name and definition in the data dictionary. If you omit the CONSTRAINT keyword, Oracle Lite generates a name with this form: POL_SYS_CONSn, where n is an integer that makes the name unique within the database. |
constraint |
The name of the constraint being added. |
NULL |
Specifies that a column can contain null values. |
NOT NULL |
Specifies that a column cannot contain null values. By default, a column can contain nulls. |
UNIQUE |
Designates a column, or a combination of columns, as a unique key. |
PRIMARY KEY |
Designates a column, or a combination of columns, as the table's primary key. |
KEY COLUMNS = |
This specifies how many columns should be used to create the index. This clause is useful when an index is needed on a large number of columns, since it reduces the size of the index. Query performance may suffer when multiple rows qualify as prefix columns of an index key as given by the KEY COLUMNS value, since the database looks up all qualifying rows to find the matching row(s). |
number |
An integer which specifies the number of KEY COLUMNS. |
FOREIGN KEY |
Designates a column, or a combination of columns in the child table, as the foreign key in a referential integrity constraint. |
schema |
The name of the schema, which is a character string up to 128 characters. The schema name must be different from any user names since each user name comes with a default schema with the same name. If you create a schema with the same name as a user name, Oracle Lite returns an error. See CREATE USER for more information. |
REFERENCES |
Identifies the primary key or unique key of the parent table that is referenced by a foreign key in a referential integrity constraint. |
table |
Specifies the table on which the constraint is placed. If you specify only table and omit the column argument, the foreign key automatically references the primary key of the table. |
column |
Specifies the column of the table on which the constraint is placed. |
ON DELETE CASCADE |
Specifies that Oracle Lite maintains referential integrity by automatically removing dependent foreign key values when you remove a referenced primary key or unique key value. |
CHECK |
Specifies that a condition be checked for each row in the table. Oracle Lite only supports the following operators and functions in CHECK conditions: + - / * = ! = < > < = > = IS NULL, LIKE, BETWEEN TO_NUMBER, TO_DATE, TRANSLATE |
condition |
Specifies the condition that each row in the table must satisfy. For more information about creating a valid condition, see Specifying SQL Conditions. |
The following example creates a table T, with columns A and B. The example uses the PRIMARY KEY constraint clause to make column A the table's primary key:
CREATE TABLE T (A CHAR(20) PRIMARY KEY, B CHAR(20));
Creates a database.
None.
Table 4-10 Arguments Used with the CREATE DATABASE Command
The number of pages should be less than or equal to 64.
Keywords may be listed in any order.
Before you can run a newly created database, you must first configure its ODBC data source name (DSN) using the ODBC Administrator. See the Oracle Lite User's Guide for more information about creating a DSN or using the ODBC Administrator.
Unlike other DDL statements, Oracle Lite autocommits the CREATE DATABASE command. You cannot undo the CREATE DATABASE command with a ROLLBACK statement.
To create the data file LIN.ODB in the directory C:\TMP with the .ODB file extension, use:
CREATE DATABASE "C:\TMP\LIN"
To create a call specification for a stored function.
A stored function (also called a user function) is a Java stored procedure that returns a value. Stored functions are very similar to procedures, except that a procedure does not return a value to the environment in which it is called. For a general discussion of procedures and functions, see "CREATE PROCEDURE". For examples of creating functions, see the CREATE FUNCTION examples.
A call specification declares a Java method so that it can be called from SQL. The call specification tells Oracle Lite which Java method to invoke when a call is made. It also tells Oracle Lite what type conversions to make for the arguments and return value.
The CREATE FUNCTION statement creates a function as a standalone schema object. For information on dropping a stand-alone function, see "DROP FUNCTION".
To create a function in your own schema, you must be connected to the database as SYSTEM or you must have DBA/DDL privileges.
To invoke a call specification, you must have DBA/DDL privileges.
Table 4-11 Parameters Used with the CREATE FUNCTION Command
Argument | Description | |
---|---|---|
OR REPLACE |
Recreates the function if it already exists. Use this clause to change the definition of an existing function without dropping, re-creating, and regranting object privileges previously granted on the function. Users who had previously been granted privileges on a redefined function can still access the function without being regranted the privileges. If any function-based indexes depend on the function, Oracle Lite marks the indexes DISABLED. |
|
schema |
The schema to contain the function. If you omit schema, Oracle Lite creates the function in your current schema. |
|
function |
The name of the function to create. See "Usage Notes". |
|
argument |
The name of an argument to the function. If the function does not accept arguments, you can omit the parentheses following the function name. |
|
IN |
Specifies that you must supply a value for the argument when calling the function. This is the default. |
|
OUT |
Specifies that the function sets the value of the argument. |
|
IN OUT |
Specifies that a value for the argument can be supplied by you and may be set by the function.
These effects may or may not occur on any particular call. You should use NOCOPY only when these effects do not matter. |
|
datatype |
The datatype of an argument. An argument can have any datatype supported by SQL. The datatype cannot specify a length, precision, or scale. Oracle Lite derives the length, precision, or scale of an argument from the environment from which the function is called. |
|
RETURN datatype |
Specifies the datatype of the function's return value. Because every function must return a value, this clause is required. The return value can have any datatype supported by SQL. The datatype cannot specify a length, precision, or scale. Oracle Lite derives the length, precision, or scale of the return value from the environment from which the function is called. |
|
IS |
Associates the SQL identifier with the Java method. |
|
AS |
Associates the SQL identifier with the Java method. |
|
invoker_rights_clause |
For compatibility with Oracle, Oracle Lite recognizes but does not enforce the invoker_rights_clause. |
|
call_spec |
Maps the Java method name, parameter types, and return type to their SQL counterparts. |
|
|
LANGUAGE |
Specifies the call_spec language. In Oracle8 this can be C or Java. In Oracle Lite, this can only be Java. |
|
java_declaration |
Identifies the method name in the Java class. |
JAVA NAME |
The Java method name. |
|
string |
Identifies the Java implementation of the method. For more information, see the Oracle Lite Java Developer's Guide. |
User-defined functions cannot be used in situations that require an unchanging definition. You cannot use user-defined functions:
In addition, when a function is called from within a query or DML statement, the function cannot:
Except for the restriction on OUT and IN OUT parameters, Oracle Lite enforces these restrictions not only for the function called directly from the SQL statement, but also for any functions that the function calls. Oracle Lite also enforces these restrictions on any functions called from the SQL statements executed by that function or any function it calls.
The following example provides complete instructions for creating and testing a function.
public class Employee { public static String paySalary (float sal, float fica, float sttax, float ss_pct, float espp_pct) { float deduct_pct; float net_sal; /* compute take-home salary */ deduct_pct = fica + sttax + ss_pct + espp_pct; net_sal = sal * deduct_pct; String returnstmt = "Net salary is " + net_sal; return returnstmt; } /*paySalary */ }
Employee
class into the Oracle Lite database. Once loaded, the Employee
class methods become stored procedures in the Oracle Lite database:
CREATE JAVA CLASS USING BFILE ('C:\', 'Employee.class');
CREATE FUNCTION PAY_SALARY( sal float, fica float, sttax float, ss_pct float, espp_pct float) return varchar2 as language java name 'Employee.paySalary (float, float, float, float, float) return java.lang.String'; . /
SELECT PAY_SALARY(6000.00, 0.2, 0.0565, 0.0606, 0.1) from dual;
Returns the following result:
PAY_SALARY ----------------------------------------- Net Salary is 2502.6
Purpose
The CREATE GLOBAL TEMPORARY TABLE command creates a temporary table which can be transaction specific or session specific. For transaction-specific temporary tables, data exists for the duration of the transaction. For session-specific temporary table, data exists for the duration of the session. Data in a temporary table is private to the session. Each session can only view and modify its own data. On rollback of a transaction, all modifications made to the global temporary table are lost.
Argument | Description |
---|---|
name |
An optionally qualified table name. |
schema |
A schema, which has the same name as the user who owns it. If omitted, the default schema name is used. |
column |
The name of a table column. |
datatype |
The datatype of the column. Cannot be used in subquery. |
DEFAULT |
Specifies a default value expr (expression) for the new column. It can be one of the following: For more information about expressions, see "Specifying Expressions". |
Temporary tables cannot be partitioned, organized into an index, or clustered.
You cannot specify any referential integrity (foreign key) constraints on temporary tables.
The following statement creates a temporary table FLIGHT_SCHEDULE for use in an automated airline reservation scheduling system. Each client has its own session and can store temporary schedules. The temporary schedules are deleted at the end of the session.
CREATE GLOBAL TEMPORARY TABLE flight_schedule (startdate DATE, enddate DATE, cost NUMBER) ON COMMIT PRESERVE ROWS;
Creates an index on one or more columns of a table.
The table to be indexed must be in your own schema. You must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-13 Arguments Used with the CREATE INDEX Command
Argument | Description |
---|---|
UNIQUE |
Designates the specified column or combination of columns as a unique key. |
schema |
When it follows CREATE INDEX, this is the schema that contains the index. If you omit schema, Oracle Lite creates the index in your own schema. When used in the ON clause, the schema that contains the table for which the index is created. |
index |
The name of the index to create. You can create any number of indexes for a table, provided you do not use the same columns and column order for more than one index. |
table |
The name of the table for which the index is created. If you do not qualify table with a schema, Oracle Lite assumes that the table is contained in your own schema. |
column |
The name of a column in the table. A column of an index cannot be of the datatype LONG or LONG RAW. |
ASC | DESC |
Provided for DB2 compatibility only. Indexes are always created in ascending order. |
KEY COLUMNS = |
This specifies how many columns should be used to create the index. This clause is useful when an index is needed on a large number of columns, since it reduces the size of the index. Query performance may suffer when multiple rows qualify as prefix columns of an index key as given by the KEY COLUMNS value. The database looks up all qualifying rows to find the matching row(s). |
number |
An integer which specifies the number of KEY COLUMNS. |
You can use additional index creation options for tuning purposes. However, only use these options when necessary as they may degrade your database performance. See Appendix D, "Index Creation Options" for more information.
CREATE ANY INDEX can be used to create a index in another schema, but this requires the DBA/DDL role.
The following example creates an index on the SAL column of the EMP table:
CREATE INDEX SAL_INDEX ON EMP(SAL);
CONSTRAINT clause, CREATE TABLE, DROP INDEX
To create a schema object containing a Java source, class, or resource.
Note: For information on Java concepts, including Java stored procedures and JDBC, see the Oracle Lite Java Developer's Guide. |
To create or replace a schema object containing a Java source, class, or resource in your own schema, you must be connected to the database as SYSTEM or you must have DBA/DDL privileges.
Table 4-14 Arguments Used with the CREATE JAVA Command
When Oracle Lite loads a Java class into the database, it does not load dependent classes. Generally, you should use the loadjava
utility to load Java classes into the database. See the Oracle Lite Java Developer's Guide for more information about the loadjava
utility.
The following statement creates a schema object and loads the specified Java class into the newly created schema object:
CREATE JAVA CLASS USING BFILE (bfile_dir, 'Agent.class');
This example assumes the directory path bfile_dir, which points to the operating system directory containing the Java class Agent.class, already exists. In this example, the name of the class determines the name of the Java class schema object.
The following statement creates a Java source schema object:
CREATE OR REPLACE JAVA SOURCE AS/* This is a class Test */ import java.math.*; /* */ public class Test {public static BigDecimal myfunc(BigDecimal a, BigDecimal b) { return a.add(b); } public static Strin myfunc2(String a, String b) { return (a+b); }};
Note: The keyword "public class" should not be used in a comment before the first public class statement. |
The following statement creates a Java resource schema object named APPTEXT from a binary file:
CREATE JAVA RESOURCE NAMED "appText" USING BFILE ('C:\TEMP', 'textBundle.dat');
To create a call specification for a stand-alone stored procedure.
A call specification ("call spec") declares a Java method so that it can be called from SQL. The call spec tells Oracle which Java method to invoke when a call is made. It also tells Oracle Lite what type conversions to make for the arguments and return value.
Stored procedures offer advantages in the areas of development, integrity, security, and memory allocation. For more information on stored procedures, including how to call stored procedures, see the Oracle Lite Java Developer's Guide.
Stored procedures and stored functions are similar. While a stored function returns a value to the environment in which it is called, a stored procedure does not. For information specific to functions, see "CREATE FUNCTION".
The CREATE PROCEDURE statement creates a procedure as a stand-alone schema object. For information on dropping a stand-alone procedure, see "DROP PROCEDURE".
To create a procedure in your own schema, you must be connected to the database as SYSTEM or you must have DBA/DDL privileges.
Table 4-15 Arguments Used with the Create Procedure Command
Oracle Lite recognizes but does not enforce the <invoker_rights_clause>. Oracle Lite always uses current_user for AUTHID.
The following example creates and compiles a Java procedure and tests it against an Oracle Lite database:
import java.sql.*; public class EMPTrigg { public static final String goodGuy = "Oleg"; public static void NameUpdate(String oldName, String[] newName) { if (oldName.equals(goodGuy)) newName[0] = oldName; } public static void SalaryUpdate(String name, int oldSalary, int newSalary[]) { if (name.equals(goodGuy)) newSalary[0] = Math.max(oldSalary, newSalary[0])*10; } public static void AfterDelete(Connection conn, String name, int salary) { if (name.equals(goodGuy)) try { Statement stmt = conn.createStatement(); stmt.executeUpdate( "insert into employee values('" + name + "', " + salary + ")"); stmt.close(); } catch(SQLException e) {} } }
CREATE TABLE EMPLOYEE (NAME VARCHAR(32), SALARY INT);
INSERT INTO EMPLOYEE VALUES ('Alice', 100); INSERT INTO EMPLOYEE VALUES ('Bob', 100); INSERT INTO EMPLOYEE VALUES ('Oleg', 100);
CREATE JAVA CLASS USING BFILE ('c:\', 'EMPTrigg.class');
CREATE PROCEDURE name_update( old_name in varchar2, new_name in out varchar2) is language java name 'EMPTrigg.NameUpdate (java.lang.String, java.lang.String[])'; / CREATE PROCEDURE salary_update( ename varchar2, old_salary int, new_salary in out int) as language java name 'EMPTrigg.SalaryUpdate (java.lang.String, int, int[])'; / CREATE PROCEDURE after_delete( ename varchar2, salary int) as language java name 'EMPTrigg.AfterDelete (java.sql.Connection, java.lang.String, int)'; /
CREATE TRIGGER NU BEFORE UPDATE OF NAME ON EMPLOYEE FOR EACH ROW name_update (old.name, new.name); / CREATE TRIGGER SU BEFORE UPDATE OF SALARY ON EMPLOYEE FOR EACH ROW salary_update (name, old.salary, new.salary); / CREATE TRIGGER AD AFTER DELETE ON EMPLOYEE FOR EACH ROW after_delete (name, salary); /
SELECT * FROM EMPLOYEE;
Returns the following result:
NAME SALARY -------------------------------- --------- Alice 100 Bob 100 Oleg 100
Creates a schema or an owner of tables, indexes, and views. CREATE SCHEMA can also be used to create multiple tables and views in a single transaction.
The CREATE SCHEMA statement can include the CREATE TABLE, CREATE VIEW, and GRANT statements. To issue a CREATE SCHEMA statement, you must be logged into the database as SYSTEM or as a user with DBA/DDL or ADMIN privileges.
Table 4-16 Arguments Used with the CREATE SCHEMA Command
Argument | Description |
---|---|
schema |
The name of the schema, which is a character string of up to 128 characters. The schema name must be different from any user names since each user name has a default schema with the same name. If you create a schema with the same name as a user name, Oracle Lite returns an error. See CREATE USER for more information. |
CREATE TABLE |
A CREATE TABLE statement to be issued as part of the CREATE SCHEMA statement. |
command |
Contains all the arguments and keywords for a CREATE TABLE or CREATE VIEW command. |
To create a sample schema called HOTEL_OPERATION use:
CREATE SCHEMA HOTEL_OPERATION;
To create the schema HOTEL_OPERATION together with the table HOTEL_DIR and the view LARGE_HOTEL use:
CREATE SCHEMA HOTEL_OPERATION CREATE TABLE HOTEL_DIR( HOTELNAME CHAR(40) NOT NULL, RATING INTEGER, ROOMRATE FLOAT, LOCATION CHAR(20) NOT NULL, CAPACITY INTEGER);
Although the CREATE SCHEMA command is not part of the ODBC SQL syntax, ODBC passes the command through to your database.
GRANT, CREATE TABLE, CREATE VIEW
Creates a sequence.
None.
Table 4-17 Arguments Used with the CREATE SEQUENCE Command
Argument | Description |
---|---|
schema |
The name of the schema to contain the sequence. If you omit schema, Oracle Lite creates the sequence in your own schema. |
sequence |
The name of the sequence to be created. |
INCREMENT BY |
Specifies the interval between sequence numbers. Can be any positive or negative integer, but cannot be 0. If negative, then the sequence descends. If positive, the sequence ascends. If you omit the INCREMENT BY clause, the default is 1. |
START WITH |
Specifies the first sequence number to be generated. Use this option to start an ascending sequence at a value greater than its minimum (which is the default), or to start a descending sequence at a value less than its maximum (which is the default). |
MAXVALUE |
Specifies the maximum value the sequence can generate. This integer value can have 9 or fewer digits. MAXVALUE must be greater than MINVALUE. |
NOMAXVALUE |
Specifies a maximum value of 2147483647 for an ascending sequence or -1 for a descending sequence. |
MINVALUE |
Specifies the minimum value that the sequence can generate. This integer value can have 9 or fewer digits. MINVALUE must be less than MAXVALUE. |
NOMINVALUE |
Specifies a minimum value of 1 for an ascending sequence or -2147483647 for a descending sequence. |
Oracle Lite commits sequence numbers when you access the NEXTVAL function. However, unlike Oracle, Oracle Lite does not automatically commit sequences. As a result, you can roll back sequences in Oracle Lite. To maintain a sequence when using the ROLLBACK command, you must commit the sequence after you create it.
The following statement creates the sequence ESEQ:
CREATE SEQUENCE ESEQ INCREMENT BY 10;
The first reference to ESEQ.NEXTVAL returns 1. The second returns 11. Each subsequent reference returns a value 10 greater than the previous one.
Although the CREATE SEQUENCE command is not part of the ODBC SQL syntax, ODBC passes the command through to your database.
Creates a public or private SQL synonym.
None.
Table 4-18 Arguments Used with the CREATE SYNONYM Command
A private synonym name must be distinct from all other objects in its schema.
You can only use synonyms with the INSERT, SELECT, UPDATE, and DELETE statements. You cannot use synonyms with the DROP statement.
To define the synonym PROD for the table PRODUCT in the schema SCOTT, issue the following statement:
CREATE SYNONYM PROD FOR SCOTT.PRODUCT;
CREATE TABLE, CREATE VIEW, CREATE SEQUENCE, DROP SYNONYM
Creates a database table.
Also, creates and populates a database table based on the result of a specified subquery. The datatypes for the column are derived from the subquery's result set. See "Usage Notes", for more information.
To create a table in your schema or another schema, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-19 Arguments Used with the CREATE TABLE Command
Argument | Description |
---|---|
schema |
A schema, which has the same name as the user who owns it. If omitted, the default schema name is used. |
table |
The name of a database table. Table names may not contain the period "." character, nor begin with an underscore "_" character. |
column |
The name of a table column. |
datatype |
The datatype of the column. Cannot be used in subquery. |
DEFAULT |
Specifies a default value expr (expression) for the new column, or a new default expr for an existing column. It can be one of the following: For more information about expressions, see "Specifying Expressions". |
column_constraint |
Adds a column integrity constraint. For more information, see "CONSTRAINT clause". |
table_constraint |
Adds a table integrity constraint. For more information, see "CONSTRAINT clause". |
AS subquery |
A SELECT statement. |
CREATE ANY TABLE can be used to create a table in another schema, but this requires the DBA/DDL role.
Each table can have up to 1000 columns, and no more than one primary key constraint.
The following syntax is not supported by Oracle Lite:
CREATE TABLE <newtablename> AS SELECT * FROM <oldtablename>;
You must create the table using the appropriate DDL, then you can copy the existing table into the new table using the following statement:
INSERT INTO <newtablename> SELECT * FROM <oldtablename>; commit;
If column_list is omitted:
If column_list is included:
If an ORDER BY clause is used in the subquery, the data is inserted in that order into the table. This normally results in clustering of the data according to the order by columns, but it is not guaranteed.
The following statement creates a table HOTEL_DIR with two columns: HOTEL_NAME, the primary key, and CAPACITY, which is not nullable and has the default value 0.
CREATE TABLE HOTEL_DIR (HOTEL_NAME CHAR(40) PRIMARY KEY, CAPACITY INTEGER DEFAULT 0 NOT NULL)
The following statement creates a table HOTEL_RESTAURANT:
CREATE TABLE HOTEL_RESTAURANT(REST_NAME CHAR(50) UNIQUE, HOTEL_NAME CHAR(40) REFERENCES HOTEL_DIR, RATING FLOAT DEFAULT NULL)
The columns include:
The table has the following integrity constraints:
Note: For additional examples you can also view the sample script, poldemo.sql which is located in the Oracle_Home\Mobile\SDK\DBS directory. This script builds the polite.odb demonstration database. |
CONSTRAINT clause, DROP TABLE, ALTER TABLE, SELECT
Creates and enables a database trigger.
None.
Table 4-20 Arguments Used with the CREATE TRIGGER Command
The following example provides you with instructions for creating and testing a trigger.
import java.lang.*;import java.sql.*; class TriggerExample {public void EMP_SAL(Connection conn, int new_sal) { System.out.println("new salary is :"+new_sal); } }
ALTER TABLE EMP ATTACH JAVA SOURCE "TriggerExample" in '.';
CREATE TRIGGER SAL_CHECK BEFORE UPDATE OF SAL ON EMP FOR EACH ROW EMP_SAL(NEW.SAL); . /
update emp set sal=sal+5000 where sal=70000;
Returns the following result:
new salary is:75000 1 row updated
ALTER TRIGGER, ALTER VIEW, CREATE VIEW, DROP TRIGGER
Creates a database user with no privileges.
To create users in your schema or other schemas, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-21 Arguments Used with the CREATE USER Command
You can create multiple users in Oracle Lite by using the CREATE USER command. A user is not a schema. When you create a user, Oracle Lite creates a schema with the same name and automatically assigns it to that user as the default schema. The name of the new user appears in the ALL_USERS view. The new user's default schema appears in the POL__SCHEMATA view.
When you connect to an Oracle Lite database as a user, the user name becomes the default schema for that session. If there is no schema to match the user name, Oracle Lite refuses the connection. You can access database objects in the default schema without prefixing them with the schema name.
Users with the appropriate privileges can create additional schemas by using the CREATE SCHEMA command, but only the default schema can connect to the database. These schemas are owned by the user who created them and require the schema name prefix to access their objects.
When you create a database using the CREATEDB utility or the CREATE DATABASE command, Oracle Lite creates a special user called SYSTEM. This user has all database privileges and is not assigned a password. You can assign a password to SYSTEM, if required. You can use SYSTEM as the default user name until you establish user names of your own as needed.
Oracle Lite does not permit a user other than SYSTEM to access data or perform operations in a schema that is not its own. Users can only access data and perform operations in a different user's schema if one of the following conditions is met:
CREATE USER SCOTT IDENTIFIED BY TIGER;
Creates or replaces a view.
You must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
FORCE creates the view regardless of whether the view's base tables or the referenced object types exist or the owner of the schema containing the view has privileges on them. These conditions must be true before any SELECT, INSERT, UPDATE, or DELETE statements can be issued against the view.
NO FORCE creates the view only if the base tables exist and the owner of the schema containing the view has privileges on them. This is the default.
Table 4-22 Arguments Used with the CREATE VIEW Command
A view is updatable if:
CREATE ANY VIEW can be used to create a view in another schema, but this requires the DBA/DDL role.
The FORCE option of CREATE VIEW behaves differently under Oracle Lite. There are two cases:
The following example creates a view called EMP_SAL which displays the name, job, and salary of each row in the EMP table:
CREATE VIEW EMP_SAL (Name, Job, Salary) AS SELECT ENAME, JOB, SAL FROM EMP; SELECT * FROM EMP_SAL;
Returns the following result:
NAME JOB SALARY ---------- --------- --------- KING PRESIDENT 5000 BLAKE MANAGER 2850 CLARK MANAGER 2450 JONES MANAGER 2975 MARTIN SALESMAN 1250 ALLEN SALESMAN 1600 TURNER SALESMAN 1500 JAMES CLERK 950 WARD SALESMAN 1250 FORD ANALYST 3000 SMITH CLERK 800 SCOTT ANALYST 3000 ADAMS CLERK 1100 MILLER CLERK 1300 14 rows selected.
Although the ODBC SQL syntax for CREATE VIEW does not support the OR REPLACE argument, ODBC passes the command through to your database.
Most ODBC-based tools require a primary key before allowing updates on a view. Oracle Lite does not report primary keys for views, so you must issue SQL commands to perform updates or deletes on views using the WHERE clause to specify the target row or rows.
DROP SEQUENCE, CREATE TABLE, DROP VIEW
Removes rows from a table or from a view's base table.
You can only delete rows from tables or views in your schema.
Table 4-23 Arguments Used with the DELETE Command
Argument | Description |
---|---|
schema |
The schema that contains the table or view. If you omit schema, Oracle Lite assumes the table or view is in your own schema. |
table |
The name of a table from which you want to delete rows. |
view |
The name of the view. If you specify view, Oracle Lite deletes rows from the view's base tables. |
WHERE condition |
Deletes only rows that satisfy a condition specified with the condition argument. For more information about creating a valid condition, see Specifying SQL Conditions. |
If no WHERE clause is specified, then all rows of the table are deleted.
A positioned DELETE requires that the cursor be updatable.
DELETE FROM PRICE WHERE MINPRICE < 2.4;
The ODBC SQL syntax for DELETE is the same as the SQL syntax. In addition, ODBC syntax includes the CURRENT
OF
cursor_name keyword and argument. These are used in the WHERE clause to specify the cursor where the DELETE operation occurs, as follows:
WHERE CURRENT OF cursor_name
Removes an integrity constraint from the database.
The DROP clause only appears in an ALTER TABLE statement. To drop an integrity constraint, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-24 Arguments Used with the DROP Clause
Argument | Description |
---|---|
PRIMARY KEY |
Drops the table's PRIMARY KEY constraint. |
UNIQUE |
Drops the UNIQUE constraint from the specified columns. |
COLUMN |
Drops a column from the table. |
column |
Specifies the column from which a column constraint is removed, or in the case of DROP COLUMN, specifies the column to be dropped from the table. |
CONSTRAINT |
Drops the integrity constraint named constraint. For more information, see "CONSTRAINT clause". |
constraint |
The name of the integrity constraint to drop. |
RESTRICT |
If any integrity constraints depend on the constraint to drop, the DROP command fails. |
CASCADE |
Drops all other integrity constraints that depend on the constraint specified in the CONSTRAINT clause. |
ALTER TABLE EMP DROP COLUMN COMM;
ALTER TABLE, CONSTRAINT clause
To remove a stand-alone stored function from the database. For information on creating a function, see "CREATE FUNCTION".
To drop a function, you must meet one of the following requirements:
The following statement drops the PAY_SALARY function, which you created in the CREATE FUNCTION example. When you drop the PAY_SALARY function, you invalidate all objects that depend on PAY_SALARY.
DROP FUNCTION PAY_SALARY;
Removes an index from the database.
To drop an index, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-26 Arguments Used with the DROP INDEX Command
Argument | Description |
---|---|
schema |
The schema that contains the index to drop. If you omit the schema, Oracle Lite assumes that the index is in your own schema. |
index |
The name of the index to drop. |
The following example drops an index on the SAL column of the EMP table:
DROP INDEX SAL_INDEX;
To drop a Java class or resource schema object.
For more information on resolving Java classes, and resources, see the Oracle Lite Java Developer's Guide.
To drop a class or resource schema object, you must meet the following requirements:
Oracle Lite recognizes schema_name when specified, but does not enforce it.
The following statement drops the Java class MyClass:
DROP JAVA CLASS "MyClass";
To remove a stand-alone stored procedure from the database. Do not use this statement to remove a procedure that is part of a package. Instead, either drop the entire package using the DROP PACKAGE statement, or redefine the package without the procedure using the CREATE PACKAGE statement with the OR REPLACE clause.
For information on creating a procedure, see "CREATE PROCEDURE".
The procedure must be connected to the database as schema or you must have DBA/DDL privileges.
Table 4-28 Arguments Used with the DROP PROCEDURE Command
The following statement drops the procedure TRANSFER owned by the user KERNER and invalidates all objects that depend on TRANSFER:
DROP PROCEDURE kerner.transfer
Removes a schema from the database.
To drop a schema, you must be logged into the database as SYSTEM or as a user with DBA/DDL or ADMIN privileges.
Table 4-29 Arguments Used with the DROP SCHEMA Command
Argument | Description |
---|---|
schema |
The schema to drop from the database. |
CASCADE |
Specifies that all other objects whose definitions depend on the specified schema are automatically dropped with the schema. |
RESTRICT |
Specifies that if there are other objects whose definitions depend on the specified schema, the DROP SCHEMA operation fails. |
If no options are specified, the default behavior is determined by the RESTRICT argument.
The following example drops the HOTEL_OPERATION schema you created in the CREATE SCHEMA example:
DROP SCHEMA HOTEL_OPERATION CASCADE;
Removes a sequence from the database.
You must be logged into the database as SYSTEM, or the sequence must be in your schema.
Table 4-30 Arguments Used with the DROP SEQUENCE Command
One method for restarting a sequence is to drop and recreate it. For example, if you have a sequence with a current value of 150 and you would like to restart the sequence with a value of 27, you would:
The following example drops the ESEQ sequence you created in the CREATE SEQUENCE example:
DROP SEQUENCE ESEQ;
Although the DROP SEQUENCE command is not part of the ODBC SQL syntax, ODBC passes the command through to your database.
ALTER SEQUENCE, CREATE SEQUENCE
Drops a public or private SQL sequence from the database.
To drop a synonym from the database, you must be logged into the database as SYSTEM, or the synonym must be in your schema.
Table 4-31 Arguments Used with the DROP SYNONYM Command
The following example drops the synonym named PROD, which you created in the CREATE SYNONYM example:
DROP SYNONYM PROD;
Removes a table from the database.
To drop a table from the database, you must be logged into the database as SYSTEM or as a user with DBA/DDL privileges.
Table 4-32 Arguments Used with the DROP TABLE Command
If no options are specified and there are no referential integrity constraints that refer to the table, Oracle Lite drops the table. If no options are specified and there are referential integrity constraints that refer to the table, Oracle Lite returns an error message.
DROP TABLE EMP;
Removes a database trigger from the database.
You must be logged into the database as SYSTEM or the trigger must be in your schema.
Table 4-33 Arguments Used with the DROP TRIGGER Command
Argument | Description |
---|---|
schema |
The schema that contains the trigger. If you omit schema, Oracle Lite assumes that the trigger is in your own schema. |
trigger |
The name of the trigger. |
The following statement drops the SAL_CHECK trigger, which you created in the CREATE TRIGGER example:
DROP TRIGGER ruth.reorder
Removes a user from the database.
To drop a user from the database, you must be logged into the database as SYSTEM, or you must have DBA/DDL or ADMIN privileges.
Table 4-34 Arguments Used with the DROP USER Command
Argument | Description |
---|---|
user |
Name of the user to be dropped. |
CASCADE |
Drops all objects associated with the user. |
You can drop users if you are connected to the database as SYSTEM, or if you are granted the ADMIN or DBA/DDL role.
The following statement drops the user Michael:
DROP USER MICHAEL;
Removes a view from the database.
To drop a view from the database, you must be logged into the database and you must meet one of the following requirements:
Argument | Description |
---|---|
schema |
The schema that contains the view to drop. If you omit schema, Oracle Lite assumes that the view is in your own schema. |
view |
The name of the view to be removed from the database. |
CASCADE |
Specifies that all other views whose definitions depend on the specified view are automatically dropped with the view. |
RESTRICT |
Specifies that if there are other views whose definitions depend on the specified view, the DROP VIEW operation fails. |
If no options are specified, Oracle Lite drops only this view. Other dependent views are not affected.
The following statement drops the EMP_SAL view you created in the CREATE VIEW example:
DROP VIEW EMP_SAL;
CREATE SYNONYM, CREATE TABLE, CREATE VIEW
Displays the execution plan chosen by the Oracle Lite database optimizer for subquery::= statements.
Table 4-36 Arguments Used with the EXPLAIN PLAN Command
Argument | Description |
---|---|
EXPLAIN PLAN |
Determines an execution plan on a query. |
select_command |
The query for which you determine the execution plan. |
Oracle Lite outputs the execution plan to a file called execplan.txt. Oracle Lite appends each new execution plan to the file.
For every execution of the EXPLAIN PLAN command, Oracle Lite outputs a single line of the EXPLAIN COMMAND followed by one or more lines of the execution plan.
The execution plan contains one line per query block. A query block begins with a subquery::= keyword.
The plan output is indented to indicate nesting. All siblings of UNION and MINUS are also indented. Each line of the plan output has the following general form:
table-name [(column-name)] [{NL(rows)|IL(rows)} table-name [(column-name)] ]Table 4-37 Parameters of the EXPLAIN PLAN Output
The tables are executed from left to right. The left-most table forms the outer-most loop of iteration.
Oracle Lite uses row estimates to order tables, however, the actual values are not important. The optimizer estimates the best possible index. The object kernel may choose a different index since it is more accurate at execution time.
Grants the ADMIN, DBA, DDL, or RESOURCE roles to users, or grants privileges on a database object to users. The DBA role is recommended as a replacement for the DDL role wherever possible.
To grant roles, you must be logged into the database as SYSTEM, or as a user with DBA/DDL and ADMIN privileges, or with RESOURCE privileges to GRANT privilege on your own objects to other users.
Table 4-38 Arguments Used with the GRANT Command
Oracle Lite combines some privileges into pre-defined roles for convenience. In many cases it is easier to grant a user a pre-defined role than to grant specific privileges in another schema. Oracle Lite does not support creating or dropping roles. The following is a list of Oracle Lite pre-defined roles:
Table 4-39 Predefined Roles in Oracle Lite
If privilege_list is ALL, then the user can INSERT, DELETE, UPDATE, or SELECT from the table or view. If privilege_list is either INSERT, DELETE, UPDATE, or SELECT, then the user has that privilege on a table.
When you grant UPDATE on a table to a user and then subsequently alter the table by adding a column, the user is not able to update the new column. The user can only update the new column if you issue a grant statement after creating the new column. For example:
CREATE TABLE t1 (c1 NUMBER c2 INTEGER); CREATE USER a IDENTIFIED BY a; GRANT SELECT, UPDATE ON t1 TO a; ALTER TABLE t1 ADD c3 INT; COMMIT;
In the preceding example, the GRANT statement must be issued after the ALTER TABLE statement or the user can not update the new column, c3.
The following example creates a user named MICHAEL and grants the user the ADMIN role:
CREATE USER MICHAEL IDENTIFIED BY SWORD; GRANT ADMIN TO MICHAEL;
The following example creates a user named MICHAEL and grants INSERT and DELETE privileges on the EMP table the user.
CREATE USER MICHAEL IDENTIFIED BY SWORD; GRANT INSERT, DELETE ON EMP TO MICHAEL;
The following example grants ALL privileges on the PRODUCT table to the newly created user, MICHAEL:
GRANT ALL ON PRODUCT TO MICHAEL;
Adds rows to a table or to a view's base table.
To insert rows into a table or view, you must be logged into the database as SYSTEM, or the table and view must be in your schema.
Table 4-40 Arguments Used with the INSERTCommand
Argument | Description |
---|---|
schema |
The schema that contains the table or view. If you omit schema, Oracle Lite assumes that the table or view is in your own schema. |
table |
The name of the table into which you want to insert rows. |
view |
The name of the view into whose base tables you want to insert rows. |
column |
A column of a table or view. In the inserted row, each column listed in this argument is assigned a value from the VALUES clause or from the subquery. If you omit one of the table's columns from this argument, the column's value for the inserted row is the column's default value as specified when the table is created. If you omit the column argument, the VALUES clause or the query must specify values for all columns in the table. |
VALUES |
Specifies a row of values to be inserted into the table or view. You specify in the VALUES clause a value for each column in the column argument. |
expr |
The values assigned to the corresponding column. This can contain host variables. For more information, see "Specifying Expressions". |
subquery |
A SELECT statement that returns rows that are inserted into the table. The SELECT list of this subquery must have the same number of columns as the column list of the INSERT statement. |
INSERT INTO EMP (EMPNO, ENAME, DEPTNO) VALUES ('7010', 'VINCE', '20');
The LEVEL pseudocolumn can be used in a SELECT statement that performs a hierarchical query. 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. In a hierarchical query, a root node is the highest node within an inverted tree, a child node is any non-root node, a parent node is any node that has children, and a leaf node is any node without children.
None.
The number of levels returned by a hierarchical query is limited to 32.
The following statement returns all employees in hierarchical order. The root row is defined to be the employee whose job is PRESIDENT. The child rows of a parent row are defined to be those who have the employee number of the parent row as their manager number.
SELECT LPAD(' ',2*(LEVEL-1)) || ename org_chart, empno, mgr, job FROM emp START WITH job = 'PRESIDENT' CONNECT BY PRIOR empno = mgr;
Returns the following result:
ORG_CHART EMPNO MGR JOB ------------------ --------- --------- --------- 7839 PRESIDENT JONES 7566 7839 MANAGER SCOTT 7788 7566 ANALYST ADAMS 7876 7788 CLERK FORD 7902 7566 ANALYST SMITH 7369 7902 CLERK CLARK 7782 7839 MANAGER MILLER 7934 7782 CLERK BLAKE 7698 7839 MANAGER WARD 7521 7698 SALESMAN JAMES 7900 7698 CLERK TURNER 7844 7698 SALESMAN ALLEN 7499 7698 SALESMAN MARTIN 7654 7698 SALESMAN 14 rows selected.
Revokes the ADMIN, DBA/DDL, or RESOURCE roles from users, or revokes privileges on a database object from users. The DBA role is recommended as a replacement for the DDL role.
To revoke roles from users, you must be logged into the database as SYSTEM or as a user with DBA or ADMIN privileges.
Table 4-41 Arguments Used with the REVOKE Command
If privilege_list contains INSERT, DELETE, UPDATE, or SELECT, then the user has those privileges on a table or view. If privilege_list is ALL, then the user can INSERT, DELETE, UPDATE, or SELECT from the table or view.
The following example creates a user named STEVE and grants the user the ADMIN role. Then, the example revokes the ADMIN role from the user, STEVE.
CREATE USER STEVE IDENTIFIED BY STINGRAY; GRANT ADMIN TO STEVE; REVOKE ADMIN FROM STEVE;
The following example revokes the INSERT and DELETE privileges on the EMP table from the user, SCOTT.
REVOKE INSERT,DELETE ON EMP FROM SCOTT;
The following example creates a user named CHARLES and grants the user the INSERT and DELETE privileges on the PRICE table, and ALL privileges on the ITEM table. Then the example revokes all privileges for the user CHARLES on the PRICE and ITEM tables.
CREATE USER CHARLES IDENTIFIED BY VORTEX; GRANT INSERT, DELETE, UPDATE ON PRICE TO CHARLES; GRANT ALL ON ITEM TO CHARLES; REVOKE ALL ON PRICE FROM CHARLES; REVOKE ALL ON ITEM FROM CHARLES;
Undoes work performed in the current synonym.
None.
Table 4-42 Arguments Used with the ROLLBACK Command
If you are not already in a transaction, Oracle Lite starts one the first time you issue a SQL statement. All the statements you issue are considered part of the transaction until you use a COMMIT or ROLLBACK command.
The COMMIT command makes permanent changes to the data in the database, saving everything up to the start of the transaction. Before changes are committed, both the old and new data exist so that changes can be stored or the data can be restored to its prior state.
The ROLLBACK command discards pending changes made to the data in the current transaction, restoring the database to its state before the start of the transaction. You can roll back a portion of a transaction by identifying a SAVEPOINT.
Important: Oracle Lite does not automatically commit DDL commands, except for CREATE DATABASE. DDL commands in Oracle Lite are subject to rollback. |
The following example inserts a new row into the DEPT table and then rolls back the transaction. This example returns the same results for both ROLLBACK and ROLLBACK WORK.
INSERT INTO DEPT (deptno, dname, loc) VALUES (50, 'Design', 'San Francisco'); SELECT * FROM dept;
Returns the following result:
DEPTNO DNAME LOC --------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON 50 DESIGN SAN FRANCISCO ROLLBACK WORK; SELECT * FROM dept;
Returns the following result:
DEPTNO DNAME LOC --------- -------------- ------------- 10 ACCOUNTING NEW YORK 20 RESEARCH DALLAS 30 SALES CHICAGO 40 OPERATIONS BOSTON
Although the ROLLBACK command is not part of the ODBC SQL syntax, ODBC passes the command through to your database.
An ODBC program typically uses the API call SQLTransact() with the SQL_ROLLBACK flag.
For each row returned by a query, the ROWNUM pseudocolumn returns a number indicating the order in which Oracle Lite 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.
None.
If an ORDER BY clause follows ROWNUM in the same subquery, the rows are reordered by the ORDER BY clause. The results can vary depending on the way the rows are accessed. For example, if the ORDER BY clause causes Oracle Lite to use an index to access the data, Oracle Lite may retrieve the rows in a different order than without the index.
If you embed the ORDER BY clause in a subquery and place the ROWNUM condition in the top-level query, you can force the ROWNUM condition to be applied after the ordering of the rows. See Example 3.
The following example uses ROWNUM to limit the number of rows returned by a query:
SELECT * FROM emp WHERE ROWNUM < 10;
The following example follows the ORDER BY clause with ROWNUM in the same query. As a result, the rows are reordered by the ORDER BY clause and do not have the same effect as the preceding example:
SELECT * FROM emp WHERE ROWNUM < 11 ORDER BY empno;
The following query returns the ten smallest employee numbers. This is sometimes referred to as a "top-N query":
SELECT * FROM (SELECT empno FROM emp ORDER BY empno) WHERE ROWNUM < 11;
The following query returns no rows:
SELECT * FROM emp WHERE ROWNUM > 1;
The first fetched row 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, this makes the condition false. All rows subsequently fail to satisfy the condition, so no rows are returned.
The following statement assigns unique values to each row of a table:
UPDATE tabx SET col1 = ROWNUM;
To identify a point in a transaction to which you can later roll back.
None.
Once you set a savepoint you can either roll back to it or remove it later. To roll back to a savepoint use the statement:
ROLLBACK TO <
savepoint_name>
To remove a savepoint use the statement:
REMOVE SAVEPOINT <
savepoint_name>
When you roll back to remove a savepoint, all nested savepoints are also rolled back or removed. Savepoints should be removed as soon as possible to reduce memory usage.
A user defined savepoint allows you to name and mark the current point in the processing of a transaction. Used with ROLLBACK, SAVEPOINT lets you undo parts of a transaction instead of the entire transaction. When you roll back to a savepoint, any savepoint marked after that savepoint is erased. The COMMIT statement erases any savepoints marked since the last commit or rollback.
The number of active savepoints you define per session is unlimited. An active savepoint is one marked since the last commit or rollback.
The following example updates the salary for two employees, Blake and Clark. It then checks the total salary in the EMP table. The example rolls back to savepoints for each employee's salary, and updates Clark's salary.
UPDATE emp SET sal = 2000 WHERE ename = 'BLAKE'; SAVEPOINT blake_sal; UPDATE emp SET sal = 1500 WHERE ename = 'CLARK'; SAVEPOINT clark_sal; SELECT SUM(sal) FROM emp; ROLLBACK TO SAVEPOINT blake_sal; UPDATE emp SET sal = 1300 WHERE ename = 'CLARK'; COMMIT;
Retrieves data from one or more tables or views. You can also use the select statement to invoke Java stored procedures.
To select data from a table or view, you must be logged into the database as SYSTEM, or the table(s) and view(s) must be part of your schema.
Table 4-43 Arguments Used with the SELECT Command
Argument | Description |
---|---|
DISTINCT |
Returns only one copy of each set of duplicate rows selected. Duplicate rows are those with matching values for each expression in the select list. |
ALL |
Returns all rows selected, including all copies of duplicates. The default is ALL. |
* |
Selects all columns from all tables, views, or snapshots listed in the FROM clause. |
table.* |
Selects all columns from the selected table. Use the schema qualifier to select from a schema other than your own. |
view.* |
Selects all columns from the selected view. Use the schema qualifier to select from a schema other than your own. |
expr |
Selects an expression, usually based on column values, from one of the tables or views in the FROM clause. A column name in this list can be qualified with a schema only if the table or view that contains the column is itself qualified with a schema in the FROM clause. For more information, see "Specifying Expressions". |
hint |
Hints are processed by the Oracle Lite optimizer to suggest choices for statement execution. See "Hints Usage" for more information. |
/*+ ... +*/ |
Hint processed by both Oracle and Oracle Lite. |
/*% ...%*/ |
Hint processed as a comment in Oracle, processed by Oracle Lite. |
// ... // |
Hint processed by both Oracle and Oracle Lite. |
c_alias |
Provides a column alias, which is a different name for the column expression, and causes the column alias to be used in the column heading. A column alias does not affect the actual name of the column. The alias can only be used in the ORDER BY clause. It cannot be used by other clauses in the query. |
schema |
The schema that contains the selected table, view, or snapshot. If you omit schema, Oracle Lite assumes that the table, view, or snapshot resides in your own schema. |
table |
The table from which data is selected. |
view |
The view from which data is selected |
t_alias |
Provides a different name or alias for the table, view, or snapshot, for the purpose of evaluating the query. Most often used in a correlated query. Other references to the table, view, or snapshot throughout the query must refer to the alias. |
WHERE |
Restricts the rows selected to those for which the specified condition is TRUE. If you omit the WHERE clause, Oracle Lite returns all rows from the tables, views, or snapshots in the FROM clause. In an embedded SQL SELECT statement, the condition in a WHERE clause can contain host variables. WHERE specifies a conditional expression that evaluates to TRUE or FALSE. For more information, see "Specifying Expressions". |
condition |
A search condition. For more information about creating a valid condition, see Specifying SQL Conditions. |
START WITH |
Returns rows in a hierarchical order. |
CONNECT BY |
Specifies the relationship between parent and child rows in a hierarchical query. The condition defines this relationship, and must use the PRIOR operator to refer to the parent row. To find the children of the parent row, Oracle Lite evaluates the PRIOR expression for each row in the table. Rows for which the condition is TRUE are the children of the parent. For more information, see the PRIOR operator. |
GROUP BY |
Groups the selected rows based on the value of the expr argument for each row, and returns a single row of summary information for each group. |
HAVING |
Restricts the groups of rows returned to those groups for which the specified condition is TRUE. If you omit this clause, Oracle Lite returns summary rows for all groups. For more information, see Specifying SQL Conditions. |
INTERSECT |
Returns all distinct rows selected by both queries. INTERSECT has a higher precedence than UNION. |
INTERSECT ALL |
Returns all distinct rows selected by both queries, the same result as INTERSECT. This syntax is supported, but has no function. |
UNION |
Returns all distinct rows selected by either query. |
UNION ALL |
Returns all rows selected by either query, including duplicates. |
MINUS |
Returns all distinct rows selected by the first query but not the second. |
command |
Refers to all parameters of a SELECT command which is itself a parameter of another SELECT command. When entering parameters for a SELECT command within a SELECT command, you can not use the WHERE statement. |
ORDER BY |
Orders rows returned by the SELECT statement, according to the following arguments: expr (expression) orders rows based on their value for expr. The expression is based on columns in the select list, or based on columns in the tables, views, or snapshots in the FROM clause. position orders rows based on their value for the expression in this position in the select list. ASC specifies an ascending sort order. ASC is the default. DESC specifies a descending sort order. |
FOR UPDATE |
The column list in the FOR UPDATE clause is ignored. The FOR UPDATE clause can be used either before or after the ORDER BY clause. |
column |
The column to be updated. |
If you do not specify a WHERE clause and there is more than one table in the FROM clause, Oracle Lite computes a Cartesian product of all the tables involved.
You can use the LEVEL pseudocolumn in a SELECT statement to perform a hierarchical query. For more information, see LEVEL pseudocolumn. A hierarchical query cannot perform a join, nor can it select data from a view.
When you select columns with an expression, those columns must have an alias. An alias specifies names for the column expressions selected by the query. The number of aliases must match the number of expressions selected by the query. Aliases must be unique within the query.
SELECT * FROM EMP WHERE SAL = 1300;
Returns the following result:
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO --------- ---------- --------- --------- --------- --------- --------- --------- 7782 CLARK MANAGER 7839 1981-06-0 1300 10 7934 MILLER CLERK 7782 1982-01-2 1300 10
SELECT 'ID=',EMPNO, 'Name=',ENAME, 'Dept=',DEPTNO FROM EMP ORDER BY DEPTNO;
Returns the following result:
'ID EMPNO 'NAME ENAME 'DEPT DEPTNO --- --------- ----- ---------- ----- --------- ID= 7839 Name= KING Dept= 10 ID= 7934 Name= MILLER Dept= 10 ID= 7782 Name= CLARK Dept= 10 ID= 7566 Name= JONES Dept= 20 ID= 7876 Name= ADAMS Dept= 20 ID= 7788 Name= SCOTT Dept= 20 ID= 7369 Name= SMITH Dept= 20 ID= 7902 Name= FORD Dept= 20 ID= 7521 Name= WARD Dept= 30 ID= 7900 Name= JAMES Dept= 30 ID= 7844 Name= TURNER Dept= 30 ID= 7499 Name= ALLEN Dept= 30 ID= 7654 Name= MARTIN Dept= 30 ID= 7698 Name= BLAKE Dept= 30 14 rows selected.
SELECT 'ID=', EMPNO, 'Name=', ENAME, 'Dept=', DEPTNO FROM EMP WHERE SAL >= 1300;
Returns the following result:
'ID EMPNO 'NAME ENAME 'DEPT DEPTNO --- --------- ----- ---------- ----- --------- ID= 7839 Name= KING Dept= 10 ID= 7698 Name= BLAKE Dept= 30 ID= 7782 Name= CLARK Dept= 10 ID= 7566 Name= JONES Dept= 20 ID= 7499 Name= ALLEN Dept= 30 ID= 7844 Name= TURNER Dept= 30 ID= 7902 Name= FORD Dept= 20 ID= 7788 Name= SCOTT Dept= 20 ID= 7934 Name= MILLER Dept= 10 9 rows selected.
SELECT * FROM (SELECT ENAME FROM EMP WHERE JOB = 'CLERK' UNION SELECT ENAME FROM EMP WHERE JOB = 'ANALYST');
Returns the following result:
ENAME ---------- ADAMS FORD JAMES MILLER SCOTT SMITH
You can use special text in a SQL statement to pass instructions, or hints, to the Oracle Lite database optimizer. The optimizer uses these hints as suggestions for choosing an execution plan for the statement. The hint text is delimited by the following sets of symbols depending on the applications in use. All of the sample syntaxes in the diagram work from a user written application.
The /*% ... %*/ syntax is treated by the Oracle8i optimizer as a comment whereas /*+ ORDERED +*/ is processed by Oracle8i optimizer. To share the same code between Oracle Lite and Oracle8i and to specify a hint to Oracle Lite only, use the syntax /*% ORDERED %*/. To give hints to both Oracle Lite and Oracle optimizers, use the syntax /*+ ORDERED +*/. The hint text must follow the SELECT keyword. The hint text is not case sensitive.
In this example, the "ordered" hint selects the EMP table as the outermost table in the join ordering. The optimizer still attempts to pick the best possible indexes to use for execution. All other optimizations, such as view replacement and subquery unnesting are still attempted.
Select //ordered// Eno, Ename, Loc from Emp, Dept where Dept.DeptNo = Emp.DeptNo and Emp.Sal > 50000;
In this example, the hint joins the tables (Product, Item, and Ord) in the given order: Product, Item, and Ord. The hint is limited only to the subquery.
Select CustId, Name, Phone from Customer Where CustId In ( Select //ordered// Ord.CustId from Product, Item, OrdWhere Ord.OrdId = Item.OrdId AndItem.ProdId = Product.ProdId And Product.Descrip like '%TENNIS%')
CONSTRAINT clause, DELETE, UPDATE
Establishes the isolation level of the current transaction.
Note: Oracle Lite implicitly commits the current transaction before and after executing a data definition language statement. |
If you use a SET TRANSACTION statement, it must be the first statement in your transaction. However, a transaction need not have a SET TRANSACTION statement.
Table 4-44 Arguments Used with the SET TRANSACTION Command
None.
SET TRANSACTION ISOLATION LEVEL SINGLEUSER;
This command deletes all rows from the table. The statement is provided to be compatible with Oracle8i. This statement performs the same action as the following:
DELETE FROM
table_name ;
Table 4-45 Arguments Used with the TRUNCATE TABLE Command
Argument | Description |
---|---|
schema |
The schema that contains the table. |
table |
The name of the table to be truncated. |
A table cannot be truncated if it has a primary key and there are rows in the dependent tables.
TRUNCATE TABLE emp;
Changes existing values in a table or in a view's base table.
To update existing values in a database table or view, you must be logged into the database as SYSTEM, or the table(s) and view(s) must be part of your schema.
Table 4-46 Arguments Used with the UPDATE Command
Argument | Description |
---|---|
schema |
The schema that contains the table or view. If you omit schema, Oracle Lite assumes that the table or view resides in your own schema. |
table |
The name of the table to be updated. |
view |
The name of the view whose base tables you want to update. |
alias |
Relabels the name of the table or view in the other clauses of the UPDATE command. |
SET |
Indicates that the columns that follow be set to specific values. |
column |
The name of a column of the table or view to be updated. If you omit one of the table's columns in the SET clause, that column's value remains unchanged. |
expr |
The new values assigned to the corresponding column. This can contain host variables. |
subquery |
The subquery to be updated. |
WHERE |
Restricts the rows updated to those for which the specified condition is TRUE. If you omit the WHERE clause, Oracle Lite updates all rows in the table or view. |
condition |
A search condition. For more information about creating a valid condition, see Specifying SQL Conditions. |
UPDATE EMP SET SAL = SAL * .45 WHERE JOB = 'PRESIDENT';
The ODBC SQL syntax for UPDATE is the same as specified. In addition, the following syntax is supported:
WHERE CURRENT OF CURSOR cursor_name
|
![]() Copyright © 2001 Oracle Corporation. All Rights Reserved. | | Ad Choices. |
|