| Oracle8i SQL Reference Release 3 (8.1.7) Part Number A85397-01 |
|
SQL Statements:
CREATE SYNONYM to DROP ROLLBACK SEGMENT, 11 of 31
Use the DELETE statement to remove rows from a table, a partitioned table, a view's base table, or a view's partitioned base table.
For you to delete rows from a table, the table must be in your own schema or you must have DELETE privilege on the table.
For you to delete rows from the base table of a view, the owner of the schema containing the view must have DELETE privilege on the base table. Also, if the view is in a schema other than your own, you must be granted DELETE privilege on the view.
The DELETE ANY TABLE system privilege also allows you to delete rows from any table or table partition, or any view's base table.
If the SQL92_SECURITY initialization parameter is set to true, then you must have SELECT privilege on the table to perform a DELETE that references table columns (such as the columns in a where_clause).
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.
|
See Also: "Hints" and Oracle8i Performance Guide and Reference for the syntax and description of hints |
DML_table_expression_clause
|
|
Specify the schema containing the table or view. If you omit |
|
|
Specify is the name of a table or view, or the column or columns resulting from a subquery, from which the rows are to be deleted. If you specify If table (or the base table of view) contains one or more domain index columns, this statements executes the appropriate indextype delete routine. See Also: Oracle8i Data Cartridge Developer's Guide for more information on these routines |
|
|
Issuing a All table or index space released by the deleted rows is retained by the table and index. |
|
|
Specify the name of the partition or subpartition within
You need not specify the partition name when deleting values from a partitioned table. However, in some cases, specifying the partition name is more efficient than a complicated |
|
|
Specify the complete or partial name of a database link to a remote database where the table or view is located. You can delete rows from a remote table or view only if you are using Oracle's distributed functionality.
|
|
|
If you omit |
|
|
Use the
|
|
|
The |
|
|
For |
|
|
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
UNUSABLE, the DELETE statement will fail unless the SKIP_UNUSABLE_INDEXES parameter has been set to true.
where_clause
Use the where_clause to delete only rows that satisfy the condition. The condition can reference the table and can contain a subquery. You can delete rows from a remote table or view only if you are using Oracle's distributed functionality.
|
Note: If this clause contains a
See Also: "parallel_clause" for |
If you omit dblink, Oracle assumes that the table or view is located on the local database.
If you omit the where_clause, Oracle deletes all rows of the table or view.
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 deletes all rows from a table named temp_assign.
DELETE FROM temp_assign;
The following statement deletes from the emp table all sales staff who made less than $100 commission last month:
DELETE FROM emp WHERE JOB = 'SALESMAN' AND COMM < 100;
The following statement has the same effect as the preceding example, but uses a subquery:
DELETE FROM (select * from emp) WHERE JOB = 'SALESMAN' AND COMM < 100;
The following statement deletes all rows from the accounts table owned by the user blake on a database accessible by the database link dallas:
DELETE FROM blake.accounts@dallas;
The following example deletes rows of nested table projs where the department number is either 123 or 456, or the department's budget is greater than 456.78:
DELETE THE(SELECT projs FROM dept d WHERE d.dno = 123) AS p WHERE p.pno IN (123, 456) OR p.budgets > 456.78;
The following example removes rows from partition nov98 of the sales table:
DELETE FROM sales PARTITION (nov98) WHERE amount_of_sale != 0;
RETURNING Clause Example
The following example returns column sal from the deleted rows and stores the result in bind array :1:
DELETE FROM emp WHERE job = 'SALESMAN' AND COMM < 100 RETURNING sal INTO :1;
|
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|