Oracle8i SQL Reference
Release 3 (8.1.7)

Part Number A85397-01

Library

Product

Contents

Index

Go to previous page Go to beginning of chapter Go to next page

SQL Statements:
DROP SEQUENCE to UPDATE, 27 of 27


UPDATE

Purpose

Use the UPDATE statement to change existing values in a table or in a view's base table.

Additional Topics

Prerequisites

For you to update values in a table, the table must be in your own schema or you must have UPDATE privilege on the table.

For you to update values in the base table of a view,

If the SQL92_SECURITY initialization parameter is set to TRUE, then you must have SELECT privilege on the table whose column values you are referencing (such as the columns in a where_clause) to perform an UPDATE.

The UPDATE ANY TABLE system privilege also allows you to update values in any table or any view's base table.

Syntax


DML_table_expression_clause::=


subquery: see SELECT and subquery.

with_clause::=


table_collection_expression::=


set_clause::=


where_clause::=


returning_clause::=


Keywords and Parameters

hint

Specify a comment that passes instructions to the optimizer on choosing an execution plan for the statement.

You can place a parallel hint immediately after the UPDATE keyword to parallelize both the underlying scan and UPDATE operations.

See Also:

 

DML_table_expression_clause

schema 

Specify the schema containing the table or view. If you omit schema, Oracle assumes the table or view is in your own schema.  

table | view | subquery 

Specify the name of the table or view, or the columns returned by a subquery, to be updated. Issuing an UPDATE statement against a table fires any UPDATE triggers associated with the table. If you specify view, Oracle updates the view's base table.

If table (or the base table of view) contains one or more domain index columns, this statement executes the appropriate indextype update routine.

See Also: Oracle8i Data Cartridge Developer's Guide for more information on these routines

 

PARTITION (partition) | SUBPARTITION (subpartition) 

Specify the name of the partition or subpartition within table targeted for updates. You need not specify the partition name when updating values in a partitioned table. However in some cases specifying the partition name can be more efficient than a complicated where_clause.  

dblink 

Specify a complete or partial name of a database link to a remote database where the table or view is located. You can use a database link to update a remote table or view only if you are using Oracle's distributed functionality.  

 

If you omit dblink, Oracle assumes the table or view is on the local database.

See Also: "Referring to Objects in Remote Databases" for information on referring to database links

 

with_clause 

Use the with_clause to restrict the subquery in one of the following ways: 

 

  • WITH READ ONLY specifies that the subquery cannot be updated.

 

 

  • WITH CHECK OPTION specifies that Oracle prohibits any changes to that table that would produce rows that are not included in the subquery.

    See Also: "WITH CHECK OPTION Example"

 

Restrictions on the DML_table_expression_clause:

table_collection_expression

Use the table_collection_expression to inform Oracle that the collection value expression should be treated as a table. You can use a table_collection_expression to update rows in one table based on rows from another table. For example, you could roll up four quarterly sales tables into a yearly sales table.

collection_expression 

Specify a subquery that selects a nested table column from table or view


Note: In earlier releases of Oracle, table_collection_expr was expressed as "THE subquery". That usage is now deprecated. 


t_alias

Specify a correlation name (alias) for the table, view, or subquery to be referenced elsewhere in the statement.


Note: This alias is required if the DML_query_expression_clause references any object type attributes or object type methods. 


set_clause

The set_clause lets you set column values.

column 

Specify the name of a column of the table or view that is to be updated. If you omit a column of the table from the set_clause, that column's value remains unchanged.  

 

Restrictions:

  • If column refers to a LOB object attribute, you must first initialize it with a value of empty or null. You cannot update it with a literal. Also, if you are updating a LOB value using some method other than a direct UPDATE SQL statement, you must first lock the row containing the LOB.

    See Also: "LOB Locking Example"

 

 

  • If column is part of the partitioning key of a partitioned table, UPDATE will fail if you change a value in the column that would move the row to a different partition or subpartition, unless you enable row movement.

    See Also: The row_movement_clause of CREATE TABLE or ALTER TABLE

 

subquery 

Specify a subquery that returns exactly one row for each row updated.

  • If you specify only one column in the set_clause, the subquery can return only one value.

  • If you specify multiple columns in the set_clause, the subquery must return as many values as you have specified columns.

If the subquery returns no rows, then the column is assigned a null.

See Also: SELECT and subquery and "Using Subqueries"

 

 

Note: If this subquery refers to remote objects, the UPDATE operation can run in parallel as long as the reference does not loop back to an object on the local database. However, if the subquery in the DML_query_expression_clause refers to any remote objects, the UPDATE operation will run serially without notification.

See Also: parallel_clause in CREATE TABLE

 

expr 

Specify an expression that resolves to the new value assigned to the corresponding column. This expression can contain host variables and optional indicator variables.

See Also: The syntax description in "Expressions"

 

VALUE 

The VALUE clause lets you specify the entire row of an object table.

Restriction: You can specify this clause only for an object table.

See Also: "SET VALUE Example"

 

Note: If you insert string literals into a RAW column, during subsequent queries, Oracle will perform a full table scan rather than using any index that might exist on the RAW column.

 

where_clause

The where_clause lets you restrict the rows updated to those for which the specified condition is true. If you omit this clause, Oracle updates all rows in the table or view.

The where_clause determines the rows in which values are updated. If you do not specify the where_clause, all rows are updated. For each row that satisfies the where_clause, the columns to the left of the equals (=) operator in the set_clause are set to the values of the corresponding expressions on the right. The expressions are evaluated as the row is updated.

See Also: The syntax description of "Conditions" 

returning_clause

The returning clause retrieves the rows affected by a DML (INSERT, UPDATE, or DELETE) statement. You can specify this clause for tables and snapshots, and for views with a single base table.

expr  

Each item in the expr list must be a valid expression syntax. 

INTO 

The INTO clause indicates that the values of the changed rows are to be stored in the variable(s) specified in data_item list. 

data_item 

Each data_item is a host variable or PL/SQL variable that stores the retrieved expr value. 

For each expression in the RETURNING list, you must specify a corresponding type-compatible PL/SQL variable or host variable in the INTO list.

Restrictions:

Examples

Simple Examples

The following statement gives null commissions to all employees with the job trainee:

UPDATE emp 
    SET comm = NULL 
    WHERE job = 'TRAINEE'; 

The following statement promotes jones to manager of Department 20 with a $1,000 raise (assuming there is only one jones):

UPDATE emp 
    SET job = 'MANAGER', sal = sal + 1000, deptno = 20 
    WHERE ename = 'JONES'; 

The following statement increases the balance of bank account number 5001 in the accounts table on a remote database accessible through the database link boston:

UPDATE accounts@boston 
    SET balance = balance + 500 
    WHERE acc_no = 5001; 

PARTITION Example

The following example updates values in a single partition of the sales table:

UPDATE sales PARTITION (feb96) s
   SET s.account_name = UPPER(s.account_name);

Complex Example

This example shows the following syntactic constructs of the UPDATE statement:

The above UPDATE statement performs the following operations:

SET VALUE Example

The following statement updates a row of object table table1 by selecting a row from another object table table2:

UPDATE table1 p SET VALUE(p) =
   (SELECT VALUE(q) FROM table2 q WHERE p.id = q.id)
   WHERE p.id = 10;

The subquery uses the value object reference function in its expression.

Correlated Update Example

The following example updates particular rows of the projs nested table corresponding to the department whose department equals 123:

UPDATE TABLE(SELECT projs 
           FROM dept d WHERE d.dno = 123)  p 
  SET p.budgets = p.budgets + 1 
  WHERE p.pno IN (123, 456);

RETURNING Clause Example

The following example returns values from the updated row and stores the result in PL/SQL variables bnd1, bnd2, bnd3:

UPDATE emp
  SET job ='MANAGER', sal = sal + 1000, deptno = 20
  WHERE ename = 'JONES'
  RETURNING sal*0.25, ename, deptno INTO bnd1, bnd2, bnd3;


Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 1996-2000, Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index