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
BETWEEN predicate (degree > 1)
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL BETWEEN
predicate also works well for row value expressions. Much like the BETWEEN predicate for degree 1, it is defined in terms of a pair of regular comparison predicates:
A BETWEEN B AND C A BETWEEN SYMMETRIC B AND C
A >= B AND A <= C (A >= B AND A <= C) OR (A >= C AND A <= B)
The above can be factored out according to the rules listed in the manual's section about row value expression comparison predicates.
jOOQ supports the BETWEEN [SYMMETRIC]
predicate and emulates it in all SQL dialects where necessary. An example is given here:
row(BOOK.ID, BOOK.TITLE).between(1, "A").and(10, "Z");
Dialect support
This example using jOOQ:
row(BOOK.ID, BOOK.TITLE).between(1, "A").and(10, "Z")
Translates to the following dialect specific expressions:
-- ACCESS, ASE, DERBY, EXASOL, FIREBIRD, HANA, INFORMIX, MEMSQL, ORACLE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE ( ( BOOK.ID >= 1 AND ( BOOK.ID > 1 OR ( BOOK.ID = 1 AND BOOK.TITLE >= 'A' ) ) ) AND ( BOOK.ID <= 10 AND ( BOOK.ID < 10 OR ( BOOK.ID = 10 AND BOOK.TITLE <= 'Z' ) ) ) ) -- AURORA_MYSQL, DUCKDB, MARIADB, MYSQL ( (BOOK.ID, BOOK.TITLE) >= (1, 'A') AND (BOOK.ID, BOOK.TITLE) <= (10, 'Z') ) -- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, H2, HSQLDB, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TRINO, VERTICA, -- YUGABYTEDB (BOOK.ID, BOOK.TITLE) BETWEEN (1, 'A') AND (10, 'Z') -- TERADATA ( (BOOK.ID, BOOK.TITLE) >= ( SELECT 1, 'A' FROM ( SELECT 1 AS "dual" ) AS "dual" ) AND (BOOK.ID, BOOK.TITLE) <= ( SELECT 10, 'Z' FROM ( SELECT 1 AS "dual" ) AS "dual" ) )
(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!