| Oracle8i SQL Reference Release 3 (8.1.7) Part Number A85397-01 |
|
SQL Statements:
DROP SEQUENCE to UPDATE, 27 of 27
Use the UPDATE statement to change existing values in a table or in a view's base table.
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,
UPDATE privilege on the view, and
UPDATE privilege on the base table.
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.
DML_table_expression_clause::=
subquery: see SELECT and subquery.
table_collection_expression::=
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
|
|
Specify the schema containing the table or view. If you omit |
|
|
|
Specify the name of the table or view, or the columns returned by a subquery, to be updated. Issuing an
If
|
|
|
|
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 |
|
|
|
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
|
|
|
|
Use the |
|
|
|
||
|
|
|
|
Restrictions on the DML_table_expression_clause:
table (or the base table of view) contains any domain indexes marked LOADING or FAILED.
order_by_clause in the subquery of the DML_query_expression_clause.
INSTEAD OF triggers if the view's defining query contains one of the following constructs:
DISTINCT operator
GROUP BY, ORDER BY, CONNECT BY, or START WITH clause
SELECT list
SELECT list
WITH CHECK OPTION, you can update the view only if the resulting data satisfies the view's defining query.
UNUSABLE, the UPDATE statement will fail unless the SKIP_UNUSABLE_INDEXES parameter has been set to TRUE.
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.
|
|
Specify a subquery that selects a nested table column from table or |
|
t_alias
Specify a correlation name (alias) for the table, view, or subquery to be referenced elsewhere in the statement.
set_clause
The set_clause lets you set column values.
|
|
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 |
|
|
|
Restrictions:
|
|
|
|
|
|
|
|
Specify a subquery that returns exactly one row for each row updated.
If the subquery returns no rows, then the column is assigned a null.
|
|
|
|
|
|
|
|
Specify an expression that resolves to the new value assigned to the corresponding column. This expression can contain host variables and optional indicator variables.
|
|
|
|
The Restriction: You can specify this clause only for an object table.
|
|
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.
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.
returning_clause can retrieve column expressions using the affected row, rowid, and REFs to the affected row and store them in host variables or PL/SQL variables.
returning_clause stores values from expressions, rowids, and REFs involving the affected rows in bind arrays.
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:
LONG types with this clause.
INSTEAD OF trigger has been defined.
See Also: PL/SQL User's Guide and Reference for information on using the
BULK COLLECT clause to return multiple values to collection variables
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;
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);
This example shows the following syntactic constructs of the UPDATE statement:
set_clause together in a single statement
where_clause to limit the updated rows
UPDATE emp a SET deptno = (SELECT deptno FROM dept WHERE loc = 'BOSTON'), (sal, comm) = (SELECT 1.1*AVG(sal), 1.5*AVG(comm) FROM emp b WHERE a.deptno = b.deptno) WHERE deptno IN (SELECT deptno FROM dept WHERE loc = 'DALLAS' OR loc = 'DETROIT');
The above UPDATE statement performs the following operations:
deptno for these employees to the deptno of Boston
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.
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);
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;
|
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|