Subqueries in a DELETE Statement - Analytics Database - Teradata Vantage

SQL Data Manipulation Language

Deployment
VantageCloud
VantageCore
Edition
Enterprise
IntelliFlex
VMware
Product
Analytics Database
Teradata Vantage
Release Number
17.20
Published
June 2022
ft:locale
en-US
ft:lastEdition
2025-04-02
dita:mapPath
pon1628111750298.ditamap
dita:ditavalPath
qkf1628213546010.ditaval
dita:id
esx1472246586715
lifecycle
latest
Product Category
Teradata Vantageā„¢

DELETE statement predicates can include subqueries that reference the delete target table, as well as other tables. The following DELETE statement is an example:

     DELETE FROM publisher
     WHERE 0 = (SELECT COUNT(*)
                FROM book
                WHERE book.pub_num=publisher.pub_num);

Two publishers have books in the library and two publishers do not.

The subquery executes once for each row of the outer reference, the publisher table. Because two publishers have no books in the library, the two rows that represent those publishers are deleted from the publisher table.

To modify this DELETE to use a noncorrelated subquery, change the subquery code to include all tables it references in its FROM clause.

     DELETE FROM publisher
     WHERE 0 = (SELECT COUNT(*)
                FROM book, publisher
                WHERE book.pub_num=publisher.pub_num);

When coded this way, the subquery predicate has a local defining reference, so the DELETE statement does not contain a correlated subquery. The count, determined once, is nonzero, so no rows are deleted.