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:
CREATE SYNONYM to DROP ROLLBACK SEGMENT, 11 of 31


DELETE

Purpose

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.

Additional Topics

Prerequisites

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).

Syntax


DML_table_expression_clause::=


subquery: See SELECT and subquery.

with_clause::=


table_collection_expression::=


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.

See Also: "Hints" and Oracle8i Performance Guide and Reference for the syntax and description of hints 

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 |snapshot | subquery 

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 view, Oracle deletes rows from the view's base table.

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 

PARTITION (partition_name) and SUBPARTITION (subpartition_name) 

Issuing a DELETE statement against a table fires any DELETE triggers defined on the table.

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 table targeted for deletes.

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 where_clause.  

dblink 

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.

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

 

 

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

with_clause 

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

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

  • WITH CHECK OPTION indicates 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"

 

table_collection_expression 

The table_collection_expression lets you inform Oracle that the collection value expression should be treated as a table. You can use a table_collection_expression to delete only those rows that also exist in another table.  

 

For collection_expression, specify a subquery that selects a nested table column from table or view

 

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

 

Restrictions on the DML_table_expression_clause:

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.

See Also: "Conditions" for the syntax of condition 


Note: If this clause contains a subquery that refers to remote objects, the DELETE 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" for CREATE TABLE  


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.

t_alias 

Provide a correlation name for the table, view, subquery, or collection value to be referenced elsewhere in the statement. Table aliases are generally used in DELETE statements with correlated queries.  

 

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

 

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

Basic Examples

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;

Remote Database Example

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;

Nested Table Example

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;

Partition Example

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;

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