Click here to view and discuss this page in DocCommentXchange. In the future, you will be sent there automatically.

SQL Anywhere 17 » SQL Anywhere Server - SQL Reference » SQL statements » Alphabetical list of SQL statements

EXCEPT statement

Returns the set difference of two query blocks.

Syntax
[ WITH temporary-views ] main-query-block
EXCEPT [ ALL | DISTINCT ] except-query-block
[ ORDER BY [ integer | select-list-expression-name ] [ ASC | DESC ], ... ]
[ FOR XML xml-mode ]
[ OPTION( query-hint, ... ) ]
query-hint :
MATERIALIZED VIEW OPTIMIZATION option-value
| FORCE OPTIMIZATION
| option-name = option-value
main-query-block :  query-block
except-query-block : query-block
option-name : identifier
option-value : 
hostvar (indicator allowed)
| string
| identifier
| number
Parameters
  • main-query-block

    A query block, comprising a SELECT statement or a query expression (possibly nested). Query blocks are explained in the documentation for comment elements in SQL.

  • except-query-block

    A query block, comprising a SELECT statement or a query expression (possibly nested). Query blocks are explained in the documentation for comment elements in SQL.

  • FOR XML clause

    This clause is defined in the documentation for the SELECT statement.

  • OPTION clause

    Use this clause to specify hints for executing the statement. The following hints are supported:

    • MATERIALIZED VIEW OPTIMIZATION option-value
    • FORCE OPTIMIZATION
    • option-name = option-value. A OPTION( isolation_level = ... ) specification in the query text overrides all other means of specifying isolation level for a query.
Remarks

The EXCEPT statement returns all rows in main-query-block except those that also appear in the except-query-block. Specify EXCEPT or EXCEPT DISTINCT if you do not want duplicates from main-query-block to appear as duplicates in the result. Otherwise, specify EXCEPT ALL. Query blocks can be nested.

The use of EXCEPT alone is equivalent to EXCEPT DISTINCT.

The main-query-block and the except-query-block must be UNION-compatible; they must each have the same number of items in their respective SELECT lists, and the types of each expression should be comparable. If corresponding items in two SELECT lists have different data types, the database server chooses a data type for the corresponding column in the result and automatically convert the columns in each query-block appropriately.

EXCEPT ALL implements bag difference rather than set difference. For example, if main-query-block contains 5 (duplicate) rows with specific values, and except-query-block contains 2 duplicate rows with identical values, then EXCEPT ALL will return 3 rows.

The results of EXCEPT are the same as the results of EXCEPT ALL if main-query-block does not contain duplicate rows.

The column names displayed are the same column names that are displayed for the first query-block and these names are used to determine the expression names to be matched with the ORDER BY clause. An alternative way of customizing result set column names is to use a common table expression (the WITH clause).

Privileges

You must own the tables referenced in query-block, or have the SELECT ANY TABLE privilege.

Side effects

None

Standards
  • ANSI/ISO SQL Standard

    EXCEPT DISTINCT is a Core Feature. EXCEPT ALL comprises the optional ANSI/ISO SQL Language Feature F304. Explicitly specifying the DISTINCT keyword with EXCEPT is optional ANSI/ISO SQL Language Feature T551. Specifying an ORDER BY clause with EXCEPT is ANSI/ISO SQL Language Feature F850. A query-block that contains an ORDER BY clause constitutes ANSI/ISO SQL Feature F851. A query block that contains a row-limit clause (SELECT TOP or LIMIT) comprises optional ANSI/ISO SQL Language Feature F857 or F858, depending on the context. The FOR XML clause and the OPTION clause are not in the standard.

  • Transact-SQL

    EXCEPT is not supported by Adaptive Server Enterprise. However, both EXCEPT ALL and EXCEPT DISTINCT can be used in the Transact-SQL dialect supported by SQL Anywhere.