Updated on 2024-05-07 GMT+08:00

DELETE

Description

Deletes rows that satisfy the WHERE clause from the specified table. If the WHERE clause is absent, the effect is to delete all rows in the table. The result is a valid, but an empty table.

Precautions

  • The owner of a table, users granted with the DELETE permission on the table, or users granted with the DELETE ANY TABLE permission can delete data from the table. When separation of duties is disabled, a system administrator has the permission to delete data from the table by default, as well as the SELECT permission on any table in the USING clause or whose values are read in condition.
  • For row-store replication tables, DELETE can be performed only in the following two scenarios:
    • Scenarios with primary key constraints.
    • Scenarios where the execution plan can be pushed down.
  • The syntax for deleting multiple tables is not applicable to viewsand tables containing RULE.
  • For a DELETE statement whose subquery is a STREAM plan, UPDATE cannot be performed on the deleted row data.

Syntax

Delete a single table:

[ WITH [ RECURSIVE ] with_query [, ...] ]
DELETE [/*+ plan_hint */] [FROM] [ ONLY ] table_name [ * ] [ [ [partition_clause]  [ [ AS ] alias ] ] | [ [ [ AS ] alias ] [partitions_clause] ] ]
    [ USING using_list ]
    [ WHERE condition | WHERE CURRENT OF cursor_name ]
    [ ORDER BY {expression [ [ ASC | DESC | USING operator ]
    [ LIMIT { count } ]
    [ RETURNING { * | { output_expr [ [ AS ] output_name ] } [, ...] } ];

Delete multiple tables:

[ WITH [ RECURSIVE ] with_query [, ...] ]
DELETE [/*+ plan_hint */] [FROM] 
    {[ ONLY ] table_name [ * ] [ [ [partition_clause]  [ [ AS ] alias ] ] | [ [ [ AS ] alias ] [partitions_clause] ] ]} [, ...]
    [ USING using_list ]
    [ WHERE condition ];

or

[ WITH [ RECURSIVE ] with_query [, ...] ]
DELETE [/*+ plan_hint */]
    {[ ONLY ] table_name [ * ] [ [ [partition_clause]  [ [ AS ] alias ] ] | [ [ [ AS ] alias ] [partitions_clause] ] ]} [, ...]
    [ FROM using_list ]
    [ WHERE condition ];

Format of with_query:

with_query_name [ ( column_name [, ...] ) ] AS [ [ NOT ] MATERIALIZED ]
( {select | values | insert | update | delete} )

Parameters

  • WITH [ RECURSIVE ] with_query [, ...]

    Specifies one or more subqueries that can be referenced by name in the main query, which is equivalent to a temporary table.

    If RECURSIVE is specified, it allows a SELECT subquery to reference itself by name.

    • with_query_name specifies the name of the result set generated by a subquery. Such names can be used to access the subquery result set.

    • column_name specifies the column name displayed in the subquery result set.
    • Each subquery can be a SELECT, VALUES, INSERT, UPDATE or DELETE statement.
    • You can use MATERIALIZED or NOT MATERIALIZED to modify the CTE.
      • If MATERIALIZED is specified, the WITH query will be materialized, and a copy of the subquery result set is generated. The copy is directly queried at the reference point. Therefore, the WITH subquery cannot be jointly optimized with the SELECT statement trunk (for example, predicate pushdown and equivalence class transfer). In this scenario, you can use NOT MATERIALIZED for modification. If the WITH query can be executed as a subquery inline, the preceding optimization can be performed.
      • If the user does not explicitly declare the materialized attribute, comply with the following rules: If the CTE is referenced only once in the trunk statement to which it belongs and semantically supports inline execution, it will be rewritten as subquery inline execution. Otherwise, the materialized execution will be performed in CTE Scan mode.
  • plan_hint

    Follows the DELETE keyword in the /*+ */ format. It is used to optimize the plan of a DELETE statement block. For details, see Hint-based Tuning. In each statement, only the first /*+ plan_hint */ comment block takes effect as a hint. Multiple hints can be written.

  • ONLY

    If ONLY is specified before the table name, matching rows are deleted from the named table only. If ONLY is not specified, matching rows are also deleted from any tables inheriting from the named table.

  • table_name

    Specifies the name (optionally schema-qualified) of the target table.

    Value range: an existing table name

    You can use database links to perform operations on remote tables. For details, see DATABASE LINK.

  • partition_clause

    Deletes a specified partition.

    PARTITION { ( partition_name ) | FOR ( partition_value [, ...] ) } |

    SUBPARTITION { ( subpartition_name ) | FOR ( subpartition_value [, ...] ) }

    For details about the keywords, see SELECT.

    For details, see CREATE TABLE SUBPARTITION.

  • partitions_clause

    Deletes multiple partitions.

    PARTITION { ( { partition_name | subpartition_name } [, ...] ) }

    This syntax takes effect only when sql_compatibility is set to 'B'.

    For details about the keywords, see SELECT.

    For details, see CREATE TABLE SUBPARTITION.

  • alias

    Specifies a substitute name for the target table.

    Value range: a string. It must comply with the naming convention.

  • using_list

    Specifies the USING clause.

    When sql_compatibility is set to 'B' or multiple tables are to be deleted , the target tables can appear at the same time when using_list specifies the set of associated tables. In addition, the aliases of the tables can be defined and used in the target tables. In other situations, the target tables cannot appear repeatedly in using_list.

  • condition

    Specifies an expression that returns a Boolean value. Only rows for which this expression returns true will be deleted. You are not advised to use numeric types such as int for condition, because such types can be implicitly converted to bool values (non-zero values are implicitly converted to true and 0 is implicitly converted to false), which may cause unexpected results.

  • WHERE CURRENT OF cursor_name

    When the cursor points to a row in a table, you can use this syntax to delete the row. For details about the restrictions, see UPDATE.

  • ORDER BY

    For details about the keywords, see SELECT.

  • LIMIT

    For details about the keywords, see SELECT.

  • output_expr

    Specifies an expression to be computed and returned by the DELETE statement after each row is deleted. The expression can use any column names of the table. Write * to return all columns.

  • output_name

    Specifies a name to use for a returned column.

    Value range: a string. It must comply with the naming convention.

Examples

-- Create a schema.
gaussdb=# CREATE SCHEMA tpcds;

-- Create the tpcds.customer_address table.
gaussdb=# CREATE TABLE tpcds.customer_address
(
ca_address_sk         INTEGER           NOT NULL,
ca_address_id         CHARACTER(16)     NOT NULL,
ca_street_number      INTEGER                    ,
ca_street_name        CHARACTER (20)
);

-- Insert multiple records into the table.
gaussdb=# INSERT INTO tpcds.customer_address VALUES (1, 'AAAAAAAABAAAAAAA', '18', 'Jackson'),(10000, 'AAAAAAAACAAAAAAA', '362', 'Washington 6th'),(15000, 'AAAAAAAADAAAAAAA', '585', 'Dogwood Washington');

-- Create the tpcds.customer_address_bak table.
gaussdb=# CREATE TABLE tpcds.customer_address_bak AS TABLE tpcds.customer_address;

-- Delete employees whose ca_address_sk is smaller than 14888 from the tpcds.customer_address_bak table.
gaussdb=# DELETE FROM tpcds.customer_address_bak WHERE ca_address_sk < 14888;

-- Delete all data from the tpcds.customer_address_bak table.
gaussdb=# DELETE FROM tpcds.customer_address_bak;

Delete the tpcds.customer_address_bak table.
gaussdb=# DROP TABLE tpcds.customer_address_bak;

-- Delete employees whose ca_address_sk is less than 50 from tables tpcds.customer_address and tpcds.customer_address_bak.
gaussdb=# DELETE FROM a,b USING tpcds.customer_address a,tpcds.customer_address_bak b where a.ca_address_sk = b.ca_address_sk and a.ca_address_sk < 50;
or
gaussdb=# DELETE a,b FROM tpcds.customer_address a,tpcds.customer_address_bak b where a.ca_address_sk = b.ca_address_sk and a.ca_address_sk < 50;

-- Delete the tpcds.customer_address table.
gaussdb=# DROP TABLE tpcds.customer_address;

-- Delete a schema.
gaussdb=# DROP SCHEMA tpcds CASCADE;

Suggestions

  • delete

    To delete all records in a table, use the TRUNCATE syntax.