Available in versions: Dev (3.19) | Latest (3.18) | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11 | 3.10 | 3.9
EXCEPT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
EXCEPT
(or MINUS
in Oracle) is the operation that returns only those values that are returned exclusively in the first subselect. By default, this removes duplicate rows. Use EXCEPT ALL
in order to retain them, and require duplicates to appear in both subqueries.
SELECT ID FROM BOOK EXCEPT ALL SELECT ID FROM AUTHOR
create.select(BOOK.ID).from(BOOK) .exceptAll( create.select(AUTHOR.ID).from(AUTHOR)) .fetch();
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).except(select(AUTHOR.ID).from(AUTHOR)).orderBy(BOOK.ID)
Translates to the following dialect specific expressions:
-- ASE, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, POSTGRES, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB SELECT BOOK.ID FROM BOOK EXCEPT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- BIGQUERY SELECT BOOK.ID FROM BOOK EXCEPT DISTINCT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- MEMSQL SELECT t.* FROM ( SELECT BOOK.ID FROM BOOK EXCEPT SELECT AUTHOR.ID FROM AUTHOR ) t ORDER BY ID -- ORACLE SELECT BOOK.ID FROM BOOK MINUS SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- ACCESS, AURORA_MYSQL, DUCKDB, FIREBIRD, REDSHIFT /* UNSUPPORTED */
(These are currently generated with jOOQ 3.19, see #10141), or translate your own on our website
Feedback
Do you have any feedback about this page? We'd love to hear it!