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

Overview

This manual is divided into six main sections:

  • Getting started with jOOQ

    This section will get you started with jOOQ quickly. It contains simple explanations about what jOOQ is, what jOOQ isn't and how to set it up for the first time

  • SQL building

    This section explains all about the jOOQ syntax used for building queries through the query DSL and the query model API. It explains the central factories, the supported SQL statements and various other syntax elements

  • Code generation

    This section explains how to configure and use the built-in source code generator

  • SQL execution

    This section will get you through the specifics of what can be done with jOOQ at runtime, in order to execute queries, perform CRUD operations, import and export data, and hook into the jOOQ execution lifecycle for debugging

  • Tools

    This section is dedicated to tools that ship with jOOQ, such as the jOOQ's JDBC mocking feature

  • Reference

    This section is a reference for elements in this manual

Table of contents

1.
Preface
2.
Copyright, License, and Trademarks
3.
Getting started with jOOQ
3.1.
How to read this manual
3.2.
The sample database used in this manual
3.3.
Different use cases for jOOQ
3.3.1.
jOOQ as a SQL builder without code generation
3.3.2.
jOOQ as a SQL builder with code generation
3.3.3.
jOOQ as a SQL executor
3.3.4.
jOOQ for CRUD
3.3.5.
jOOQ for PROs
3.4.
Getting jOOQ
3.5.
Tutorials
3.5.1.
jOOQ in 7 easy steps
3.5.1.1.
Step 1: Preparation
3.5.1.2.
Step 2: Your database
3.5.1.3.
Step 3: Code generation
3.5.1.4.
Step 4: Connect to your database
3.5.1.5.
Step 5: Querying
3.5.1.6.
Step 6: Iterating
3.5.1.7.
Step 7: Explore!
3.5.2.
Using jOOQ with Flyway
3.5.3.
Using jOOQ with jbang
3.6.
jOOQ and Java 8
3.7.
jOOQ and JavaFX
3.8.
jOOQ and Nashorn
3.9.
jOOQ and Scala
3.10.
jOOQ and Groovy
3.11.
jOOQ and Kotlin
3.12.
jOOQ and NoSQL
3.13.
jOOQ and JPA
3.14.
Build your own
3.15.
jOOQ and backwards-compatibility
4.
SQL building
4.1.
The query DSL type
4.1.1.
DSL subclasses
4.2.
The DSLContext API
4.2.1.
SQL Dialect
4.2.2.
SQL Dialect Family
4.2.3.
Connection vs. DataSource
4.2.4.
Custom data
4.2.5.
Custom ExecuteListeners
4.2.6.
Custom Settings
4.2.6.1.
Auto-attach Records
4.2.6.2.
Backslash Escaping
4.2.6.3.
Execute Logging
4.2.6.4.
Fetch Warnings
4.2.6.5.
Identifier style
4.2.6.6.
IN-list Padding
4.2.6.7.
JDBC Flags
4.2.6.8.
Keyword style
4.2.6.9.
Map JPA Annotations
4.2.6.10.
Object qualification
4.2.6.11.
Optimistic Locking
4.2.6.12.
Parameter types
4.2.6.13.
Reflection caching
4.2.6.14.
Return All Columns On Store
4.2.6.15.
Runtime schema and table mapping
4.2.6.16.
Scalar subqueries for stored functions
4.2.6.17.
Statement Type
4.2.6.18.
Updatable Primary Keys
4.2.7.
Thread safety
4.3.
SQL Statements (DML)
4.3.1.
jOOQ's DSL and model API
4.3.2.
The WITH clause
4.3.3.
The WITH RECURSIVE clause
4.3.4.
The SELECT statement
4.3.4.1.
SELECT clause
4.3.4.1.1.
Projection type safety
4.3.4.1.2.
SelectField
4.3.4.1.3.
SELECT DISTINCT
4.3.4.1.4.
Convenience methods
4.3.4.2.
FROM clause
4.3.4.3.
JOIN operator
4.3.4.4.
WHERE clause
4.3.4.5.
CONNECT BY clause
4.3.4.6.
GROUP BY clause
4.3.4.6.1.
GROUP BY columns
4.3.4.6.2.
GROUP BY ROLLUP
4.3.4.6.3.
GROUP BY CUBE
4.3.4.6.4.
GROUP BY GROUPING SETS
4.3.4.6.5.
GROUP BY empty grouping set
4.3.4.7.
HAVING clause
4.3.4.8.
WINDOW clause
4.3.4.9.
ORDER BY clause
4.3.4.10.
LIMIT .. OFFSET clause
4.3.4.11.
SEEK clause
4.3.4.12.
FOR UPDATE clause
4.3.4.13.
Set operations
4.3.4.13.1.
Type safety
4.3.4.13.2.
Projection rowtype
4.3.4.13.3.
Differences to standard SQL
4.3.4.13.4.
UNION
4.3.4.13.5.
INTERSECT
4.3.4.13.6.
EXCEPT
4.3.4.14.
Lexical and logical SELECT clause order
4.3.5.
The INSERT statement
4.3.5.1.
INSERT .. VALUES
4.3.5.2.
INSERT .. DEFAULT VALUES
4.3.5.3.
INSERT .. SET
4.3.5.4.
INSERT .. SELECT
4.3.5.5.
INSERT .. ON DUPLICATE KEY UPDATE
4.3.5.6.
INSERT .. ON DUPLICATE KEY IGNORE
4.3.5.7.
INSERT .. ON CONFLICT
4.3.5.8.
INSERT .. RETURNING
4.3.6.
The UPDATE statement
4.3.6.1.
UPDATE .. SET
4.3.6.2.
UPDATE .. SET ROWS
4.3.6.3.
UPDATE .. FROM
4.3.6.4.
UPDATE .. WHERE
4.3.6.5.
UPDATE .. RETURNING
4.3.7.
The DELETE statement
4.3.7.1.
DELETE .. WHERE
4.3.7.2.
DELETE .. RETURNING
4.3.8.
The MERGE statement
4.4.
SQL Statements (DDL)
4.4.1.
The ALTER statement
4.4.1.1.
ALTER INDEX
4.4.1.2.
ALTER SCHEMA
4.4.1.3.
ALTER SEQUENCE
4.4.1.4.
ALTER TABLE
4.4.1.5.
ALTER VIEW
4.4.1.5.1.
ALTER VIEW .. RENAME
4.4.1.5.2.
ALTER VIEW IF EXISTS
4.4.2.
The CREATE statement
4.4.2.1.
CREATE INDEX
4.4.2.2.
CREATE SCHEMA
4.4.2.3.
CREATE SEQUENCE
4.4.2.4.
CREATE TABLE
4.4.2.4.1.
Columns
4.4.2.4.2.
Nullability
4.4.2.4.3.
Defaults
4.4.2.4.4.
Identities
4.4.2.4.5.
Primary key
4.4.2.4.6.
Unique constraints
4.4.2.4.7.
Foreign keys
4.4.2.4.8.
Check constraints
4.4.2.4.9.
From a SELECT
4.4.2.4.10.
Temporary tables
4.4.2.5.
CREATE VIEW
4.4.2.5.1.
WITH CHECK OPTION
4.4.2.5.2.
WITH READ ONLY
4.4.3.
The DROP statement
4.4.3.1.
DROP INDEX
4.4.3.1.1.
IF EXISTS
4.4.3.2.
DROP SCHEMA
4.4.3.2.1.
IF EXISTS
4.4.3.3.
DROP SEQUENCE
4.4.3.3.1.
IF EXISTS
4.4.3.4.
DROP TABLE
4.4.3.4.1.
IF EXISTS
4.4.3.5.
DROP VIEW
4.4.3.5.1.
IF EXISTS
4.4.4.
The TRUNCATE statement
4.4.5.
Generating DDL from objects
4.5.
Catalog and schema expressions
4.6.
Table expressions
4.6.1.
Generated Tables
4.6.2.
Aliased Tables
4.6.2.1.
Aliased generated tables
4.6.2.2.
Aliased table expressions
4.6.2.3.
Derived column lists
4.6.2.4.
Unnamed derived tables
4.6.3.
Joined tables
4.6.3.1.
CROSS JOIN
4.6.3.2.
INNER JOIN
4.6.3.3.
OUTER JOIN
4.6.3.4.
SEMI JOIN
4.6.3.5.
ANTI JOIN
4.6.3.6.
ON clause
4.6.3.7.
ON KEY clause
4.6.3.8.
USING clause
4.6.3.9.
NATURAL clause
4.6.3.10.
LATERAL
4.6.3.11.
APPLY
4.6.3.12.
PARTITION BY
4.6.4.
The VALUES() table constructor
4.6.5.
Derived tables
4.6.6.
The Oracle 11g PIVOT clause
4.6.7.
jOOQ's relational division syntax
4.6.8.
Array and cursor unnesting
4.6.9.
Table-valued functions
4.6.10.
GENERATE_SERIES
4.6.11.
The DUAL table
4.7.
Column expressions
4.7.1.
Table columns
4.7.1.1.
Generated table columns
4.7.1.2.
Dereferenced table columns
4.7.1.3.
Named table columns
4.7.2.
Aliased columns
4.7.3.
Cast expressions
4.7.4.
Datatype coercions
4.7.5.
Arithmetic expressions
4.7.6.
String concatenation
4.7.7.
Case sensitivity with strings
4.7.8.
General functions
4.7.8.1.
COALESCE
4.7.8.2.
DECODE
4.7.8.3.
NULLIF
4.7.8.4.
NVL
4.7.8.5.
NVL2
4.7.9.
Numeric functions
4.7.9.1.
ABS
4.7.9.2.
ACOS
4.7.9.3.
ASIN
4.7.9.4.
ATAN
4.7.9.5.
ATAN2
4.7.9.6.
CEIL
4.7.9.7.
COS
4.7.9.8.
COSH
4.7.9.9.
COT
4.7.9.10.
COTH
4.7.9.11.
DEG
4.7.9.12.
E
4.7.9.13.
EXP
4.7.9.14.
FLOOR
4.7.9.15.
GREATEST
4.7.9.16.
LEAST
4.7.9.17.
LN
4.7.9.18.
LOG
4.7.9.19.
NEG
4.7.9.20.
PI
4.7.9.21.
POWER
4.7.9.22.
RAD
4.7.9.23.
RAND
4.7.9.24.
ROUND
4.7.9.25.
SIGN
4.7.9.26.
SIN
4.7.9.27.
SINH
4.7.9.28.
SQRT
4.7.9.29.
TAN
4.7.9.30.
TANH
4.7.9.31.
TRUNC
4.7.10.
Bitwise functions
4.7.10.1.
BIT_AND
4.7.10.2.
BIT_COUNT
4.7.10.3.
BIT_NAND
4.7.10.4.
BIT_NOR
4.7.10.5.
BIT_NOT
4.7.10.6.
BIT_OR
4.7.10.7.
BIT_XNOR
4.7.10.8.
BIT_XOR
4.7.10.9.
SHL
4.7.10.10.
SHR
4.7.11.
String functions
4.7.11.1.
ASCII
4.7.11.2.
CONCAT
4.7.11.3.
LEFT
4.7.11.4.
LENGTH
4.7.11.5.
LOWER
4.7.11.6.
LPAD
4.7.11.7.
LTRIM
4.7.11.8.
MD5
4.7.11.9.
MID
4.7.11.10.
POSITION
4.7.11.11.
REPEAT
4.7.11.12.
REPLACE
4.7.11.13.
REVERSE
4.7.11.14.
RIGHT
4.7.11.15.
RPAD
4.7.11.16.
RTRIM
4.7.11.17.
SPACE
4.7.11.18.
SUBSTRING
4.7.11.19.
TRANSLATE
4.7.11.20.
TRIM
4.7.11.21.
UPPER
4.7.12.
Datetime functions
4.7.12.1.
CURRENT_DATE
4.7.12.2.
CURRENT_LOCALDATE
4.7.12.3.
CURRENT_LOCALDATETIME
4.7.12.4.
CURRENT_LOCALTIME
4.7.12.5.
CURRENT_OFFSETDATETIME
4.7.12.6.
CURRENT_OFFSETTIME
4.7.12.7.
CURRENT_TIME
4.7.12.8.
CURRENT_TIMESTAMP
4.7.12.9.
DATE
4.7.12.10.
DATEADD
4.7.12.11.
DATEDIFF
4.7.12.12.
DATESUB
4.7.12.13.
DAY
4.7.12.14.
EXTRACT
4.7.12.15.
HOUR
4.7.12.16.
LOCALDATE
4.7.12.17.
LOCALDATETIME
4.7.12.18.
LOCALTIME
4.7.12.19.
MINUTE
4.7.12.20.
MONTH
4.7.12.21.
SECOND
4.7.12.22.
TIME
4.7.12.23.
TIMESTAMP
4.7.12.24.
TIMESTAMPADD
4.7.12.25.
TO_DATE
4.7.12.26.
TO_LOCALDATE
4.7.12.27.
TO_LOCALDATETIME
4.7.12.28.
TO_TIMESTAMP
4.7.12.29.
TRUNC
4.7.12.30.
YEAR
4.7.13.
ARRAY functions
4.7.13.1.
ARRAY constructor
4.7.14.
System functions
4.7.14.1.
CURRENT_SCHEMA
4.7.14.2.
CURRENT_USER
4.7.15.
Aggregate functions
4.7.15.1.
Grouping
4.7.15.2.
Distinctness
4.7.15.3.
Filtering
4.7.15.4.
Ordering
4.7.15.5.
Ordering WITHIN GROUP
4.7.15.6.
Keeping
4.7.15.7.
ARRAY_AGG
4.7.15.8.
AVG
4.7.15.9.
BOOL_AND
4.7.15.10.
BOOL_OR
4.7.15.11.
COLLECT
4.7.15.12.
COUNT
4.7.15.13.
CUME_DIST
4.7.15.14.
DENSE_RANK
4.7.15.15.
EVERY
4.7.15.16.
GROUP_CONCAT
4.7.15.17.
LISTAGG
4.7.15.18.
MAX
4.7.15.19.
MEDIAN
4.7.15.20.
MIN
4.7.15.21.
MODE
4.7.15.22.
PERCENT_RANK
4.7.15.23.
PERCENTILE_CONT
4.7.15.24.
PERCENTILE_DISC
4.7.15.25.
PRODUCT
4.7.15.26.
RANK
4.7.15.27.
SUM
4.7.16.
Window functions
4.7.16.1.
PARTITION BY
4.7.16.2.
ORDER BY
4.7.16.3.
ROWS, RANGE, GROUPS (frame clause)
4.7.16.4.
EXCLUDE
4.7.16.5.
NULL treatment
4.7.16.6.
FROM FIRST, FROM LAST
4.7.16.7.
Nested aggregate functions
4.7.16.8.
Window aggregation
4.7.16.9.
Window ordered aggregate
4.7.16.10.
ROW_NUMBER
4.7.16.11.
RANK
4.7.16.12.
DENSE_RANK
4.7.16.13.
PERCENT_RANK
4.7.16.14.
CUME_DIST
4.7.16.15.
NTILE
4.7.16.16.
LEAD
4.7.16.17.
LAG
4.7.16.18.
FIRST_VALUE
4.7.16.19.
LAST_VALUE
4.7.16.20.
NTH_VALUE
4.7.17.
Grouping functions
4.7.18.
User-defined functions
4.7.19.
User-defined aggregate functions
4.7.20.
The CASE expression
4.7.21.
Sequences and serials
4.7.22.
Scalar subqueries
4.7.23.
Tuples or row value expressions
4.8.
Conditional expressions
4.8.1.
Condition building
4.8.2.
TRUE and FALSE condition
4.8.3.
BOOLEAN columns
4.8.4.
AND, OR, NOT boolean operators
4.8.5.
Comparison predicate
4.8.6.
Boolean operator precedence
4.8.7.
Comparison predicate (degree > 1)
4.8.8.
Quantified comparison predicate
4.8.9.
NULL predicate
4.8.10.
NULL predicate (degree > 1)
4.8.11.
DISTINCT predicate
4.8.12.
BETWEEN predicate
4.8.13.
BETWEEN predicate (degree > 1)
4.8.14.
LIKE predicate
4.8.15.
IN predicate
4.8.16.
IN predicate (degree > 1)
4.8.17.
EXISTS predicate
4.8.18.
OVERLAPS predicate
4.8.19.
Query By Example (QBE)
4.9.
Operator precedence
4.10.
Synthetic SQL clauses
4.11.
Dynamic SQL
4.12.
Plain SQL
4.13.
Plain SQL Templating Language
4.14.
Hints
4.14.1.
MySQL hints
4.14.1.1.
Index hints
4.14.1.2.
STRAIGHT_JOIN
4.14.1.3.
Oracle style hints in MySQL
4.14.2.
Oracle hints
4.14.3.
SQL Server hints
4.14.3.1.
WITH
4.14.3.2.
OPTION
4.15.
Names and identifiers
4.16.
Bind values and parameters
4.16.1.
Indexed parameters
4.16.2.
Named parameters
4.16.3.
Inlined parameters
4.16.4.
SQL injection
4.17.
QueryParts
4.17.1.
SQL rendering
4.17.2.
Declaration vs reference
4.17.3.
Pretty printing SQL
4.17.4.
Variable binding
4.17.5.
Custom data type bindings
4.17.6.
Custom syntax elements
4.17.7.
Plain SQL QueryParts
4.17.8.
Serializability
4.17.9.
Custom SQL transformation with VisitListener
4.17.9.1.
Example: Logging abbreviated bind values
4.18.
SQL Parser
4.19.
Zero-based vs one-based APIs
4.20.
SQL building in Scala
5.
SQL execution
5.1.
Comparison between jOOQ and JDBC
5.2.
Query vs. ResultQuery
5.3.
Fetching
5.3.1.
Record vs. TableRecord
5.3.2.
Record1 to Record22
5.3.3.
Arrays, Maps and Lists
5.3.4.
RecordHandler
5.3.5.
RecordMapper
5.3.6.
POJOs
5.3.7.
POJOs with RecordMappers
5.3.8.
Lazy fetching
5.3.9.
Lazy fetching with Streams
5.3.10.
Many fetching
5.3.11.
Later fetching
5.3.12.
ResultSet fetching
5.3.13.
Auto data type conversion
5.3.14.
Custom data type conversion
5.4.
Static statements vs. Prepared Statements
5.5.
Reusing a Query's PreparedStatement
5.6.
JDBC flags
5.7.
Using JDBC batch operations
5.8.
Sequence execution
5.9.
Stored procedures and functions
5.9.1.
Oracle Packages
5.9.2.
Oracle member procedures
5.10.
Exporting to XML, CSV, JSON, HTML, Text
5.10.1.
Exporting XML
5.10.2.
Exporting CSV
5.10.3.
Exporting JSON
5.10.4.
Exporting HTML
5.10.5.
Exporting Text
5.11.
Importing data
5.11.1.
The Loader API
5.11.2.
Import options
5.11.2.1.
Throttling
5.11.2.2.
Duplicate handling
5.11.2.3.
Error handling
5.11.3.
Import data sources
5.11.3.1.
Importing CSV
5.11.3.2.
Importing JSON
5.11.3.3.
Importing records
5.11.3.4.
Importing arrays
5.11.3.5.
Importing XML
5.11.4.
Import listeners
5.11.5.
Import result and error handling
5.12.
CRUD with UpdatableRecords
5.12.1.
Simple CRUD
5.12.2.
Records' internal flags
5.12.3.
IDENTITY values
5.12.4.
Navigation methods
5.12.5.
Non-updatable records
5.12.6.
Optimistic locking
5.12.7.
Batch execution
5.12.8.
CRUD SPI: RecordListener
5.13.
DAOs
5.14.
Transaction management
5.15.
Exception handling
5.16.
ExecuteListeners
5.17.
Database meta data
5.17.1.
JDBC meta data
5.17.2.
XML meta data
5.18.
JDBC Connection
5.19.
Logging with LoggerListener
5.20.
Performance considerations
5.21.
Alternative execution models
5.21.1.
Using jOOQ with Spring's JdbcTemplate
5.21.2.
Using jOOQ with JPA
5.21.2.1.
Using jOOQ with JPA Native Query
5.21.2.2.
Using jOOQ with JPA entities
5.21.2.3.
Using jOOQ with JPA EntityResult
6.
Code generation
6.1.
Configuration and setup of the generator
6.2.
Advanced generator configuration
6.2.1.
Logging
6.2.2.
Jdbc
6.2.3.
Generator
6.2.4.
Database
6.2.4.1.
Database name and properties
6.2.4.2.
RegexFlags
6.2.4.3.
Includes and Excludes
6.2.4.4.
Include object types
6.2.4.5.
Record Version and Timestamp Fields
6.2.4.6.
Synthetic identities
6.2.4.7.
Synthetic primary keys
6.2.4.8.
Override primary keys
6.2.4.9.
Date as timestamp
6.2.4.10.
Ignore procedure return values (deprecated)
6.2.4.11.
Unsigned types
6.2.4.12.
Catalog and schema mapping
6.2.4.13.
Catalog and schema version providers
6.2.4.14.
Forced types
6.2.4.14.1.
Matching of forced types
6.2.4.14.2.
Data type rewriting
6.2.4.14.3.
Qualified converters
6.2.4.14.4.
Inline converters
6.2.4.14.5.
Data type bindings
6.2.4.15.
Table valued functions
6.2.5.
Generate
6.2.5.1.
Annotations
6.2.5.2.
Covariant overrides
6.2.5.2.1.
Overriding as()
6.2.5.2.2.
Overriding rename()
6.2.5.3.
Default catalog and schema
6.2.5.4.
Fluent setters
6.2.5.5.
Fully Qualified Types
6.2.5.6.
Global Artefacts
6.2.5.7.
Java Time Types
6.2.6.
Output target configuration
6.3.
Programmatic generator configuration
6.4.
Custom generator strategies
6.5.
Matcher strategies
6.5.1.
MatcherRule
6.5.2.
Matching schemas
6.5.3.
Matching tables
6.5.4.
Matching fields
6.5.5.
Matching routines
6.5.6.
Matching sequences
6.5.7.
Matcher examples
6.6.
Custom code sections
6.7.
Generated global artefacts
6.8.
Generated tables
6.9.
Generated records
6.10.
Generated POJOs
6.11.
Generated Interfaces
6.12.
Generated DAOs
6.13.
Generated sequences
6.14.
Generated procedures
6.15.
Generated UDTs
6.16.
Mapping generated catalogs and schemas
6.17.
Code generation for large schemas
6.18.
Code generation and version control
6.19.
JPADatabase: Code generation from entities
6.20.
XMLDatabase: Code generation from XML files
6.21.
XMLGenerator: Generating XML
6.22.
Running the code generator with Maven
6.23.
Running the code generator with Ant
6.24.
Running the code generator with Gradle
6.25.
Features requiring generated code
7.
Tools
7.1.
JDBC mocking for unit testing
7.2.
API validation using the Checker Framework or Error Prone
7.3.
jOOQ Console
8.
Coming from JPA
8.1.
Set based thinking
8.2.
Database first
8.3.
Eager or lazy loading
8.4.
First level cache and second level cache
8.5.
AttributeConverter
8.6.
User types
9.
Reference
9.1.
Supported RDBMS
9.2.
Commercial only features
9.3.
Experimental features
9.4.
Data types
9.4.1.
BLOBs and CLOBs
9.4.2.
BOOLEAN data type
9.4.3.
Unsigned integer types
9.4.4.
INTERVAL data types
9.4.5.
XML data types
9.4.6.
Geospatial data types
9.4.7.
CURSOR data types
9.4.8.
ARRAY and TABLE data types
9.4.9.
Oracle DATE data type
9.5.
SQL to DSL mapping rules
9.6.
Quality Assurance
9.7.
Security
9.7.1.
SQL Injection
9.7.2.
Debug logging
9.7.3.
Exception message
9.7.4.
Contact
9.8.
Migrating to jOOQ 3.0
9.9.
Don't do this
9.9.1.
jOOQ: Implementing the DSL types
9.9.2.
jOOQ: Referencing the Step types
9.9.3.
Schema: NULL columns
9.9.4.
Schema: Unnamed constraints
9.9.5.
Schema: Unnecessary surrogate keys
9.9.6.
Schema: Wrong data types
9.9.7.
SQL: COUNT(*) instead of EXISTS()
9.9.8.
SQL: N+1
9.9.9.
SQL: NOT IN predicate
9.9.10.
SQL: Rely on implicit ordering
9.9.11.
SQL: SELECT *
9.9.12.
SQL: SELECT DISTINCT
9.9.13.
SQL: Unnecessary UNION instead of UNION ALL
9.10.
The most important jOOQ types
9.11.
Credits
 

1. Preface

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ's reason for being - compared to JPA

Java and SQL have come a long way. SQL is an "old", yet established and well-understood technology. Java is a legacy too, although its platform JVM allows for many new and contemporary languages built on top of it. Yet, after all these years, libraries dealing with the interface between SQL and Java have come and gone, leaving JPA to be a standard that is accepted only with doubts, short of any surviving options.

So far, there had been only few database abstraction frameworks or libraries, that truly respected SQL as a first class citizen among languages. Most frameworks, including the industry standards JPA, EJB, Hibernate, JDO, Criteria Query, and many others try to hide SQL itself, minimising its scope to things called JPQL, HQL, JDOQL and various other inferior query languages

jOOQ has come to fill this gap.

jOOQ's reason for being - compared to LINQ

Other platforms incorporate ideas such as LINQ (with LINQ-to-SQL), or Scala's SLICK, or also Java's QueryDSL to better integrate querying as a concept into their respective language. By querying, they understand querying of arbitrary targets, such as SQL, XML, Collections and other heterogeneous data stores. jOOQ claims that this is going the wrong way too.

In more advanced querying use-cases (more than simple CRUD and the occasional JOIN), people will want to profit from the expressivity of SQL. Due to the relational nature of SQL, this is quite different from what object-oriented and partially functional languages such as C#, Scala, or Java can offer.

It is very hard to formally express and validate joins and the ad-hoc table expression types they create. It gets even harder when you want support for more advanced table expressions, such as pivot tables, unnested cursors, or just arbitrary projections from derived tables. With a very strong object-oriented typing model, these features will probably stay out of scope.

In essence, the decision of creating an API that looks like SQL or one that looks like C#, Scala, Java is a definite decision in favour of one or the other platform. While it will be easier to evolve SLICK in similar ways as LINQ (or QueryDSL in the Java world), SQL feature scope that clearly communicates its underlying intent will be very hard to add, later on (e.g. how would you model Oracle's partitioned outer join syntax? How would you model ANSI/ISO SQL:1999 grouping sets? How can you support scalar subquery caching? etc...).

jOOQ has come to fill this gap.

jOOQ's reason for being - compared to SQL / JDBC

So why not just use SQL?

SQL can be written as plain text and passed through the JDBC API. Over the years, people have become wary of this approach for many reasons:

  • No typesafety
  • No syntax safety
  • No bind value index safety
  • Verbose SQL String concatenation
  • Boring bind value indexing techniques
  • Verbose resource and exception handling in JDBC
  • A very "stateful", not very object-oriented JDBC API, which is hard to use

For these many reasons, other frameworks have tried to abstract JDBC away in the past in one way or another. Unfortunately, many have completely abstracted SQL away as well

jOOQ has come to fill this gap.

jOOQ is different

SQL was never meant to be abstracted. To be confined in the narrow boundaries of heavy mappers, hiding the beauty and simplicity of relational data. SQL was never meant to be object-oriented. SQL was never meant to be anything other than... SQL!

 

2. Copyright, License, and Trademarks

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This section lists the various licenses that apply to different versions of jOOQ. Prior to version 3.2, jOOQ was shipped for free under the terms of the Apache Software License 2.0. With jOOQ 3.2, jOOQ became dual-licensed: Apache Software License 2.0 (for use with Open Source databases) and commercial (for use with commercial databases).

This manual itself (as well as the www.jooq.org public website) is licensed to you under the terms of the CC BY-SA 4.0 license.

Please contact legal@datageekery.com, should you have any questions regarding licensing.

License for jOOQ 3.2 and later

This work is dual-licensed
- under the Apache Software License 2.0 (the "ASL")
- under the jOOQ License and Maintenance Agreement (the "jOOQ License")
=============================================================================
You may choose which license applies to you:

- If you're using this work with Open Source databases, you may choose
  either ASL or jOOQ License.
- If you're using this work with at least one commercial database, you must
  choose jOOQ License

For more information, please visit https://www.jooq.org/licenses

Apache Software License 2.0:
-----------------------------------------------------------------------------
Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

 https://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.

jOOQ License and Maintenance Agreement:
-----------------------------------------------------------------------------
Data Geekery grants the Customer the non-exclusive, timely limited and
non-transferable license to install and use the Software under the terms of
the jOOQ License and Maintenance Agreement.

This library is distributed with a LIMITED WARRANTY. See the jOOQ License
and Maintenance Agreement for more details: https://www.jooq.org/licensing

Historic license for jOOQ 1.x, 2.x, 3.0, 3.1

Licensed under the Apache License, Version 2.0 (the "License");
you may not use this file except in compliance with the License.
You may obtain a copy of the License at

    https://www.apache.org/licenses/LICENSE-2.0

Unless required by applicable law or agreed to in writing, software
distributed under the License is distributed on an "AS IS" BASIS,
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
See the License for the specific language governing permissions and
limitations under the License.

Trademarks owned by Data Geekery™ GmbH

  • jOOλ™ is a trademark by Data Geekery™ GmbH
  • jOOQ™ is a trademark by Data Geekery™ GmbH
  • jOOR™ is a trademark by Data Geekery™ GmbH
  • jOOU™ is a trademark by Data Geekery™ GmbH
  • jOOX™ is a trademark by Data Geekery™ GmbH

Trademarks owned by database vendors with no affiliation to Data Geekery™ GmbH

  • Access® is a registered trademark of Microsoft® Inc.
  • Adaptive Server® Enterprise is a registered trademark of Sybase®, Inc.
  • CUBRID™ is a trademark of NHN® Corp.
  • DB2® is a registered trademark of IBM® Corp.
  • Derby is a trademark of the Apache™ Software Foundation
  • H2 is a trademark of the H2 Group
  • HANA is a trademark of SAP SE
  • HSQLDB is a trademark of The hsql Development Group
  • Ingres is a trademark of Actian™ Corp.
  • MariaDB is a trademark of Monty Program Ab
  • MySQL® is a registered trademark of Oracle® Corp.
  • Firebird® is a registered trademark of Firebird Foundation Inc.
  • Oracle® database is a registered trademark of Oracle® Corp.
  • PostgreSQL® is a registered trademark of The PostgreSQL Global Development Group
  • Postgres Plus® is a registered trademark of EnterpriseDB® software
  • SQL Anywhere® is a registered trademark of Sybase®, Inc.
  • SQL Server® is a registered trademark of Microsoft® Inc.
  • SQLite is a trademark of Hipp, Wyrick & Company, Inc.

Other trademarks by vendors with no affiliation to Data Geekery™ GmbH

  • Java® is a registered trademark by Oracle® Corp. and/or its affiliates
  • Liquibase is a trademark by Datical, Inc
  • Flyway is a trademark by Red Gate Software Ltd
  • Scala is a trademark of EPFL

Other trademark remarks

Other names may be trademarks of their respective owners.

Throughout the manual, the above trademarks are referenced without a formal ® (R) or ™ (TM) symbol. It is believed that referencing third-party trademarks in this manual or on the jOOQ website constitutes "fair use". Please contact us if you think that your trademark(s) are not properly attributed.

Contributions

The following are authors and contributors of jOOQ or parts of jOOQ in alphabetical order:

  • Aaron Digulla
  • Andreas Franzén
  • Anuraag Agrawal
  • Arnaud Roger
  • Art O Cathain
  • Artur Dryomov
  • Ben Manes
  • Brent Douglas
  • Brett Meyer
  • Christian Stein
  • Christopher Deckers
  • Dennis Neufeld
  • Ed Schaller
  • Eric Peters
  • Ernest Mishkin
  • Espen Stromsnes
  • Eugeny Karpov
  • Fabrice Le Roy
  • Gonzalo Ortiz Jaureguizar
  • Gregory Hlavac
  • Henrik Sjöstrand
  • Ivan Dugic
  • Javier Durante
  • Johannes Bühler
  • Joseph B Phillips
  • Joseph Pachod
  • Knut Wannheden
  • Laurent Pireyn
  • Logan Hauspie
  • Luc Marchaud
  • Lukas Eder
  • Matti Tahvonen
  • Michael Doberenz
  • Michael Simons
  • Michał Kołodziejski
  • Miguel Gonzalez Sanchez
  • Mustafa Yücel
  • Nathaniel Fischer
  • Octavia Togami
  • Oliver Flege
  • Per Lundberg
  • Peter Ertl
  • Richard Bradley
  • Robin Stocker
  • Roland Weisleder
  • Samy Deghou
  • Sander Plas
  • Sean Wellington
  • Sergey Epik
  • Sergey Zhuravlev
  • Stanislas Nanchen
  • Stephan Schroevers
  • Sugiharto Lim
  • Sven Jacobs
  • Szymon Jachim
  • Terence Zhang
  • Thomas Darimont
  • Timothy Wilson
  • Timur Shaidullin
  • Tsukasa Kitachi
  • Victor Bronstein
  • Victor Z. Peng
  • Vladimir Kulev
  • Vladimir Vinogradov
  • Vojtech Polivka
  • Wang Gaoyuan
  • Wyke Oskar
  • Xavier Oliver
  • Zoltan Tamasi

See the following website for details about contributing to jOOQ:
https://www.jooq.org/legal/contributions

 

3. Getting started with jOOQ

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

These chapters contain a quick overview of how to get started with this manual and with jOOQ. While the subsequent chapters contain a lot of reference information, this chapter here just wraps up the essentials.

 

3.1. How to read this manual

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This section helps you correctly interpret this manual in the context of jOOQ.

Code blocks

The following are code blocks:

-- A SQL code block
SELECT 1 FROM DUAL
// A Java code block
for (int i = 0; i < 10; i++);
<!-- An XML code block -->
<hello what="world"></hello>
# A config file code block
org.jooq.property=value

These are useful to provide examples in code. Often, with jOOQ, it is even more useful to compare SQL code with its corresponding Java/jOOQ code. When this is done, the blocks are aligned side-by-side, with SQL usually being on the left, and an equivalent jOOQ DSL query in Java usually being on the right:

-- In SQL:
SELECT 1 FROM DUAL
// Using jOOQ:
create.selectOne().fetch()

Code block contents

The contents of code blocks follow conventions, too. If nothing else is mentioned next to any given code block, then the following can be assumed:

-- SQL assumptions
------------------

-- If nothing else is specified, assume that the Oracle syntax is used
SELECT 1 FROM DUAL
// Java assumptions
// ----------------

// Whenever you see "standalone functions", assume they were static imported from org.jooq.impl.DSL
// "DSL" is the entry point of the static query DSL
exists(); max(); min(); val(); inline(); // correspond to DSL.exists(); DSL.max(); DSL.min(); etc...

// Whenever you see BOOK/Book, AUTHOR/Author and similar entities, assume they were (static) imported from the generated schema
BOOK.TITLE, AUTHOR.LAST_NAME // com.example.generated.Tables.BOOK.TITLE, com.example.generated.Tables.AUTHOR.LAST_NAME
FK_BOOK_AUTHOR               // com.example.generated.Keys.FK_BOOK_AUTHOR

// Whenever you see "create" being used in Java code, assume that this is an instance of org.jooq.DSLContext.
// The reason why it is called "create" is the fact, that a jOOQ QueryPart is being created from the DSL object.
// "create" is thus the entry point of the non-static query DSL
DSLContext create = DSL.using(connection, SQLDialect.ORACLE);

Your naming may differ, of course. For instance, you could name the "create" instance "db", instead.

Execution

When you're coding PL/SQL, T-SQL or some other procedural SQL language, SQL statements are always executed immediately at the semi-colon. This is not the case in jOOQ, because as an internal DSL, jOOQ can never be sure that your statement is complete until you call fetch() or execute(). The manual tries to apply fetch() and execute() as thoroughly as possible. If not, it is implied:

SELECT 1 FROM DUAL
UPDATE t SET v = 1
create.selectOne().fetch();
create.update(T).set(T.V, 1).execute();

Degree (arity)

jOOQ records (and many other API elements) have a degree N between 1 and 22. The variable degree of an API element is denoted as [N], e.g. Row[N] or Record[N]. The term "degree" is preferred over arity, as "degree" is the term used in the SQL standard, whereas "arity" is used more often in mathematics and relational theory.

Settings

jOOQ allows to override runtime behaviour using org.jooq.conf.Settings. If nothing is specified, the default runtime settings are assumed.

Sample database

jOOQ query examples run against the sample database. See the manual's section about the sample database used in this manual to learn more about the sample database.

 

3.2. The sample database used in this manual

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For the examples in this manual, the same database will always be referred to. It essentially consists of these entities created using the Oracle dialect

CREATE TABLE language (
  id              NUMBER(7)     NOT NULL PRIMARY KEY,
  cd              CHAR(2)       NOT NULL,
  description     VARCHAR2(50)
);

CREATE TABLE author (
  id              NUMBER(7)     NOT NULL PRIMARY KEY,
  first_name      VARCHAR2(50),
  last_name       VARCHAR2(50)  NOT NULL,
  date_of_birth   DATE,
  year_of_birth   NUMBER(7),
  distinguished   NUMBER(1)
);

CREATE TABLE book (
  id              NUMBER(7)     NOT NULL PRIMARY KEY,
  author_id       NUMBER(7)     NOT NULL,
  title           VARCHAR2(400) NOT NULL,
  published_in    NUMBER(7)     NOT NULL,
  language_id     NUMBER(7)     NOT NULL,

  CONSTRAINT fk_book_author     FOREIGN KEY (author_id)   REFERENCES author(id),
  CONSTRAINT fk_book_language   FOREIGN KEY (language_id) REFERENCES language(id)
);

CREATE TABLE book_store (
  name            VARCHAR2(400) NOT NULL UNIQUE
);

CREATE TABLE book_to_book_store (
  name            VARCHAR2(400) NOT NULL,
  book_id         INTEGER       NOT NULL,
  stock           INTEGER,

  PRIMARY KEY(name, book_id),
  CONSTRAINT fk_b2bs_book_store FOREIGN KEY (name)        REFERENCES book_store (name) ON DELETE CASCADE,
  CONSTRAINT fk_b2bs_book       FOREIGN KEY (book_id)     REFERENCES book (id)         ON DELETE CASCADE
);

More entities, types (e.g. UDT's, ARRAY types, ENUM types, etc), stored procedures and packages are introduced for specific examples

In addition to the above, you may assume the following sample data:

INSERT INTO language (id, cd, description) VALUES (1, 'en', 'English');
INSERT INTO language (id, cd, description) VALUES (2, 'de', 'Deutsch');
INSERT INTO language (id, cd, description) VALUES (3, 'fr', 'Français');
INSERT INTO language (id, cd, description) VALUES (4, 'pt', 'Português');

INSERT INTO author (id, first_name, last_name, date_of_birth    , year_of_birth)
  VALUES           (1 , 'George'  , 'Orwell' , DATE '1903-06-26', 1903         );
INSERT INTO author (id, first_name, last_name, date_of_birth    , year_of_birth)
  VALUES           (2 , 'Paulo'   , 'Coelho' , DATE '1947-08-24', 1947         );

INSERT INTO book (id, author_id, title         , published_in, language_id)
  VALUES         (1 , 1        , '1984'        , 1948        , 1          );
INSERT INTO book (id, author_id, title         , published_in, language_id)
  VALUES         (2 , 1        , 'Animal Farm' , 1945        , 1          );
INSERT INTO book (id, author_id, title         , published_in, language_id)
  VALUES         (3 , 2        , 'O Alquimista', 1988        , 4          );
INSERT INTO book (id, author_id, title         , published_in, language_id)
  VALUES         (4 , 2        , 'Brida'       , 1990        , 2          );

INSERT INTO book_store VALUES ('Orell Füssli');
INSERT INTO book_store VALUES ('Ex Libris');
INSERT INTO book_store VALUES ('Buchhandlung im Volkshaus');

INSERT INTO book_to_book_store VALUES ('Orell Füssli'             , 1, 10);
INSERT INTO book_to_book_store VALUES ('Orell Füssli'             , 2, 10);
INSERT INTO book_to_book_store VALUES ('Orell Füssli'             , 3, 10);
INSERT INTO book_to_book_store VALUES ('Ex Libris'                , 1, 1 );
INSERT INTO book_to_book_store VALUES ('Ex Libris'                , 3, 2 );
INSERT INTO book_to_book_store VALUES ('Buchhandlung im Volkshaus', 3, 1 );
 

3.3. Different use cases for jOOQ

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ has originally been created as a library for complete abstraction of JDBC and all database interaction. Various best practices that are frequently encountered in pre-existing software products are applied to this library. This includes:

  • Typesafe database object referencing through generated schema, table, column, record, procedure, type, dao, pojo artefacts (see the chapter about code generation)
  • Typesafe SQL construction / SQL building through a complete querying DSL API modelling SQL as a domain specific language in Java (see the chapter about the query DSL API)
  • Convenient query execution through an improved API for result fetching (see the chapters about the various types of data fetching)
  • SQL dialect abstraction and SQL clause emulation to improve cross-database compatibility and to enable missing features in simpler databases (see the chapter about SQL dialects)
  • SQL logging and debugging using jOOQ as an integral part of your development process (see the chapters about logging)

Effectively, jOOQ was originally designed to replace any other database abstraction framework short of the ones handling connection pooling (and more sophisticated transaction management)

Use jOOQ the way you prefer

... but open source is community-driven. And the community has shown various ways of using jOOQ that diverge from its original intent. Some use cases encountered are:

  • Using Hibernate for 70% of the queries (i.e. CRUD) and jOOQ for the remaining 30% where SQL is really needed
  • Using jOOQ for SQL building and JDBC for SQL execution
  • Using jOOQ for SQL building and Spring Data for SQL execution
  • Using jOOQ without the source code generator to build the basis of a framework for dynamic SQL execution.

The following sections explain about various use cases for using jOOQ in your application.

 

3.3.1. jOOQ as a SQL builder without code generation

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

We strongly recommend to use jOOQ with its code generator to get the most out of jOOQ!

However, if you have a dynamic schema, you don't have to use the code generator. This is the most simple of all use cases, allowing for construction of valid SQL for any database. In this use case, you will not use jOOQ's code generator and maybe not even jOOQ's query execution facilities. Instead, you'll use jOOQ's query DSL API to wrap strings, literals and other user-defined objects into an object-oriented, type-safe AST modelling your SQL statements. An example is given here:

// Fetch a SQL string from a jOOQ Query in order to manually execute it with another tool.
// For simplicity reasons, we're using the API to construct case-insensitive object references, here.
Query query = create.select(field("BOOK.TITLE"), field("AUTHOR.FIRST_NAME"), field("AUTHOR.LAST_NAME"))
                    .from(table("BOOK"))
                    .join(table("AUTHOR"))
                    .on(field("BOOK.AUTHOR_ID").eq(field("AUTHOR.ID")))
                    .where(field("BOOK.PUBLISHED_IN").eq(1948));
String sql = query.getSQL();
List<Object> bindValues = query.getBindValues();

The SQL string built with the jOOQ query DSL can then be executed using JDBC directly, using Spring's JdbcTemplate, using Apache DbUtils and many other tools (note that since jOOQ uses java.sql.PreparedStatement by default, this will generate a bind variable for "1948". Read more about bind variables here).

You can also avoid getting the SQL string and bind values separately:

String sql = query.getSQL(ParamType.INLINED);

If you wish to use jOOQ only as a SQL builder, the following sections of the manual will be of interest to you:

  • SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
  • Plain SQL: This section contains information useful in particular to those that want to supply table expressions, column expressions, etc. as plain SQL to jOOQ, rather than through generated artefacts
  • Bind values: This section explains how bind values are managed and/or inlined in jOOQ.
 

3.3.2. jOOQ as a SQL builder with code generation

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In addition to using jOOQ as a standalone SQL builder, you can also use jOOQ's code generation features in order to compile your SQL statements using a Java compiler against an actual database schema. This adds a lot of power and expressiveness to just simply constructing SQL using the query DSL and custom strings and literals, as you can be sure that all database artefacts actually exist in the database, and that their type is correct. We strongly recommend using this approach. An example is given here:

// Fetch a SQL string from a jOOQ Query in order to manually execute it with another tool.
Query query = create.select(BOOK.TITLE, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
                    .from(BOOK)
                    .join(AUTHOR)
                    .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
                    .where(BOOK.PUBLISHED_IN.eq(1948));

String sql = query.getSQL();
List<Object> bindValues = query.getBindValues();

The SQL string built with the jOOQ query DSL can then be executed using JDBC directly, using Spring's JdbcTemplate, using Apache DbUtils and many other tools (note that since jOOQ uses java.sql.PreparedStatement by default, this will generate a bind variable for "1948". Read more about bind variables here).

You can also avoid getting the SQL string and bind values separately:

String sql = query.getSQL(ParamType.INLINED);

If you wish to use jOOQ only as a SQL builder with code generation, the following sections of the manual will be of interest to you:

  • SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
  • Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
  • Bind values: This section explains how bind values are managed and/or inlined in jOOQ.
 

3.3.3. jOOQ as a SQL executor

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Instead of any tool mentioned in the previous chapters, you can also use jOOQ directly to execute your jOOQ-generated SQL statements. This will add a lot of convenience on top of the previously discussed API for typesafe SQL construction, when you can re-use the information from generated classes to fetch records and custom data types. An example is given here:

// Typesafely execute the SQL statement directly with jOOQ
Result<Record3<String, String, String>> result =
create.select(BOOK.TITLE, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .from(BOOK)
      .join(AUTHOR)
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .where(BOOK.PUBLISHED_IN.eq(1948))
      .fetch();

By having jOOQ execute your SQL, the jOOQ query DSL becomes truly embedded SQL.

jOOQ doesn't stop here, though! You can execute any SQL with jOOQ. In other words, you can use any other SQL building tool and run the SQL statements with jOOQ. An example is given here:

// Use your favourite tool to construct SQL strings:
String sql = "SELECT title, first_name, last_name FROM book JOIN author ON book.author_id = author.id " +
             "WHERE book.published_in = 1984";

// Fetch results using jOOQ
Result<Record> result = create.fetch(sql);

// Or execute that SQL with JDBC, fetching the ResultSet with jOOQ:
ResultSet rs = connection.createStatement().executeQuery(sql);
Result<Record> result = create.fetch(rs);

If you wish to use jOOQ as a SQL executor with (or without) code generation, the following sections of the manual will be of interest to you:

  • SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
  • Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
  • SQL execution: This section contains a lot of information about executing SQL statements using the jOOQ API
  • Fetching: This section contains some useful information about the various ways of fetching data with jOOQ
 

3.3.4. jOOQ for CRUD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Apart from jOOQ's fluent API for query construction, jOOQ can also help you execute everyday CRUD operations. An example is given here:

// Fetch an author
AuthorRecord author = create.fetchOne(AUTHOR, AUTHOR.ID.eq(1));

// Create a new author, if it doesn't exist yet
if (author == null) {
    author = create.newRecord(AUTHOR);
    author.setId(1);
    author.setFirstName("Dan");
    author.setLastName("Brown");
}

// Mark the author as a "distinguished" author and store it
author.setDistinguished(1);

// Executes an update on existing authors, or insert on new ones
author.store();

If you wish to use all of jOOQ's features, the following sections of the manual will be of interest to you (including all sub-sections):

  • SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
  • Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
  • SQL execution: This section contains a lot of information about executing SQL statements using the jOOQ API
 

3.3.5. jOOQ for PROs

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ isn't just a library that helps you build and execute SQL against your generated, compilable schema. jOOQ ships with a lot of tools. Here are some of the most important tools shipped with jOOQ:

  • jOOQ's Execute Listeners: jOOQ allows you to hook your custom execute listeners into jOOQ's SQL statement execution lifecycle in order to centrally coordinate any arbitrary operation performed on SQL being executed. Use this for logging, identity generation, SQL tracing, performance measurements, etc.
  • Logging: jOOQ has a standard DEBUG logger built-in, for logging and tracing all your executed SQL statements and fetched result sets
  • Stored Procedures: jOOQ supports stored procedures and functions of your favourite database. All routines and user-defined types are generated and can be included in jOOQ's SQL building API as function references.
  • Batch execution: Batch execution is important when executing a big load of SQL statements. jOOQ simplifies these operations compared to JDBC
  • Exporting and Importing: jOOQ ships with an API to easily export/import data in various formats

If you're a power user of your favourite, feature-rich database, jOOQ will help you access all of your database's vendor-specific features, such as OLAP features, stored procedures, user-defined types, vendor-specific SQL, functions, etc. Examples are given throughout this manual.

 

3.4. Getting jOOQ

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ is distributed over 3 main channels:

The ZIP file

If you choose to download jOOQ over the website, you will be able to download a ZIP file with the following layout:

  • maven-deploy.bat: A Windows batch script to deploy artifacts to a maven repository
  • maven-deploy.sh: A bash script to deploy artifacts to a maven repository
  • maven-install.bat: A Windows batch script to install artifacts to the local maven repository
  • maven-install.sh: A bash script to install artifacts to the local maven repository

The website hosts the latest versions of the jOOQ Open Source Edition as well as all the historic versions of the commercial jOOQ editions including snapshot builds of all distributions that are available to paying customers only.

The commercial artifact repository

The commercial artifact repository hosts all the historic versions of the commercial jOOQ editions including snapshot builds of all distributions that are available to paying customers only.

Below is information regarding how to include these dependencies in Maven / Gradle:

Maven
Gradle (Kotlin)
Gradle (Groovy)

settings.xml

<server>
    <id>jooq-pro</id>
    <username>[your licensee email]</username>
    <password>[your license key]</password>
</server>

pom.xml

<repositories>
    <repository>
        <id>central</id>
        <url>https://repo1.maven.org/maven2/</url>
    </repository>
    <!-- Other repositories ... -->

    <repository>
        <id>jooq-pro</id>
        <url>https://repo.jooq.org/repo</url>
    </repository>
</repositories>
<pluginRepositories>
    <pluginRepository>
        <id>central</id>
        <url>https://repo1.maven.org/maven2/</url>
    </pluginRepository>
    <!-- Other repositories ... -->

    <pluginRepository>
        <id>jooq-pro</id>
        <url>https://repo.jooq.org/repo</url>
    </pluginRepository>
</pluginRepositories>
// The jOOQ-codegen-gradle plugin has been introduced in version 3.19 only.
// The jOOQ-codegen-gradle plugin has been introduced in version 3.19 only.

Dependencies

Depending on the edition you're using, please declare the following dependencies in Maven or Gradle:

Maven
Gradle (Kotlin)
Gradle (Groovy)
<dependency>
    <!-- Use org.jooq                for the Open Source Edition
             org.jooq.pro            for commercial editions with Java 17 support,
             org.jooq.pro-java-11    for commercial editions with Java 11 support,
             org.jooq.pro-java-8     for commercial editions with Java 8 support,
             org.jooq.trial          for the free trial edition with Java 17 support,
             org.jooq.trial-java-11  for the free trial edition with Java 11 support,
             org.jooq.trial-java-8   for the free trial edition with Java 8 support

       Note: Only the Open Source Edition is hosted on Maven Central.
             Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org -->
    <groupId>org.jooq</groupId>
    <artifactId>jooq</artifactId>
    <version>3.9.6</version>
</dependency>
dependencies {
    // Use org.jooq                for the Open Source Edition
    //     org.jooq.pro            for commercial editions with Java 17 support,
    //     org.jooq.pro-java-11    for commercial editions with Java 11 support,
    //     org.jooq.pro-java-8     for commercial editions with Java 8 support,
    //     org.jooq.trial          for the free trial edition with Java 17 support,
    //     org.jooq.trial-java-11  for the free trial edition with Java 11 support,
    //     org.jooq.trial-java-8   for the free trial edition with Java 8 support
    //
    // Note: Only the Open Source Edition is hosted on Maven Central.
    //       Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org
    implementation("org.jooq:jooq:3.9.6")
}
dependencies {
    // Use org.jooq                for the Open Source Edition
    //     org.jooq.pro            for commercial editions with Java 17 support,
    //     org.jooq.pro-java-11    for commercial editions with Java 11 support,
    //     org.jooq.pro-java-8     for commercial editions with Java 8 support,
    //     org.jooq.trial          for the free trial edition with Java 17 support,
    //     org.jooq.trial-java-11  for the free trial edition with Java 11 support,
    //     org.jooq.trial-java-8   for the free trial edition with Java 8 support
    //
    // Note: Only the Open Source Edition is hosted on Maven Central.
    //       Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org
    implementation "org.jooq:jooq:3.9.6"
}
 

3.5. Tutorials

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Don't have time to read the full manual? Here are a couple of tutorials that will get you into the most essential parts of jOOQ as quick as possible.

 

3.5.1. jOOQ in 7 easy steps

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This manual section is intended for new users, to help them get a running application with jOOQ, quickly.

 

3.5.1.1. Step 1: Preparation

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

If you haven't already downloaded it, download jOOQ:
https://www.jooq.org/download

Alternatively, you can create a Maven dependency to download jOOQ artefacts:

Open Source Edition

<dependency>
  <groupId>org.jooq</groupId>
  <artifactId>jooq</artifactId>
  <version>3.9.6</version>
</dependency>

<!-- These may not be required, unless you use the GenerationTool manually for code generation -->
<dependency>
  <groupId>org.jooq</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.9.6</version>
</dependency>
<dependency>
  <groupId>org.jooq</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.9.6</version>
</dependency>

Commercial Editions (Java 8+)

<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution -->
<dependency>
  <groupId>org.jooq.pro</groupId>
  <artifactId>jooq</artifactId>
  <version>3.9.6</version>
</dependency>

<!-- These may not be required, unless you use the GenerationTool manually for code generation -->
<dependency>
  <groupId>org.jooq.pro</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.9.6</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.9.6</version>
</dependency>

Commercial Editions (Java 6+)

<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution -->
<dependency>
  <groupId>org.jooq.pro-java-6</groupId>
  <artifactId>jooq</artifactId>
  <version>3.9.6</version>
</dependency>

<!-- These may not be required, unless you use the GenerationTool manually for code generation -->
<dependency>
  <groupId>org.jooq.pro-java-6</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.9.6</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro-java-6</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.9.6</version>
</dependency>

Commercial Editions (Free Trial)

<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution -->
<dependency>
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq</artifactId>
  <version>3.9.6</version>
</dependency>

<!-- These may not be required, unless you use the GenerationTool manually for code generation -->
<dependency>
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.9.6</version>
</dependency>
<dependency>
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.9.6</version>
</dependency>

Note that only the jOOQ Open Source Edition is available from Maven Central. If you're using the jOOQ Professional Edition or the jOOQ Enterprise Edition, you will have to manually install jOOQ in your local Nexus, or in your local Maven cache. For more information, please refer to the licensing pages.

Please refer to the manual's section about Code generation configuration to learn how to use jOOQ's code generator with Maven.

For this example, we'll be using MySQL. If you haven't already downloaded MySQL Connector/J, download it here:
https://dev.mysql.com/downloads/connector/j/

If you don't have a MySQL instance up and running yet, get it from https://www.mysql.com or https://hub.docker.com/_/mysql now!

 

3.5.1.2. Step 2: Your database

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

We're going to create a database called "library" and a corresponding "author" table. Connect to MySQL via your command line client and type the following:

CREATE DATABASE `library`;

USE `library`;

CREATE TABLE `author` (
  `id` int NOT NULL,
  `first_name` varchar(255) DEFAULT NULL,
  `last_name` varchar(255) DEFAULT NULL,
  PRIMARY KEY (`id`)
);
 

3.5.1.3. Step 3: Code generation

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In this step, we're going to use jOOQ's command line tools to generate classes that map to the Author table we just created. More detailed information about how to set up the jOOQ code generator can be found here:
jOOQ manual pages about setting up the code generator

The easiest way to generate a schema is to copy the jOOQ jar files (there should be 3) and the MySQL Connector jar file to a temporary directory. Then, create a library.xml that looks like this:

<?xml version="1.0" encoding="UTF-8" standalone="yes"?>
<configuration>
  <!-- Configure the database connection here -->
  <jdbc>
    <driver>com.mysql.cj.jdbc.Driver</driver>
    <url>jdbc:mysql://localhost:3306/library</url>
    <user>root</user>
    <password></password>
  </jdbc>

  <generator>
    <!-- The default code generator. You can override this one, to generate your own code style.
         Supported generators:
         - org.jooq.util.JavaGenerator
         - org.jooq.util.ScalaGenerator
         Defaults to org.jooq.util.JavaGenerator

         Note the classes have been moved to org.jooq.codegen or org.jooq.meta in jOOQ 3.11 -->
    <name>org.jooq.util.JavaGenerator</name>

    <database>
      <!-- The database type. The format here is:
           org.jooq.util.[database].[database]Database

           Note the classes have been moved to org.jooq.codegen or org.jooq.meta in jOOQ 3.11 -->
      <name>org.jooq.util.mysql.MySQLDatabase</name>

      <!-- The database schema (or in the absence of schema support, in your RDBMS this
           can be the owner, user, database name) to be generated -->
      <inputSchema>library</inputSchema>

      <!-- All elements that are generated from your schema
           (A Java regular expression. Use the pipe to separate several expressions)
           Watch out for case-sensitivity. Depending on your database, this might be important! -->
      <includes>.*</includes>

      <!-- All elements that are excluded from your schema
           (A Java regular expression. Use the pipe to separate several expressions).
           Excludes match before includes, i.e. excludes have a higher priority -->
      <excludes></excludes>
    </database>

    <target>
      <!-- The destination package of your generated classes (within the destination directory) -->
      <packageName>test.generated</packageName>

      <!-- The destination directory of your generated classes. Using Maven directory layout here -->
      <directory>C:/workspace/MySQLTest/src/main/java</directory>
    </target>
  </generator>
</configuration>

Replace the username (<username/> or <user/>) with whatever user has the appropriate privileges to query the database meta data. You'll also want to look at the other values and replace as necessary. Here are the two interesting properties:

<packageName/> - set this to the parent package you want to create for the generated classes. Setting the value to test.generated will cause the test.generated.tables.Author and test.generated.tables.records.AuthorRecord classes to be created

<directory/> - the directory to output the generated classes to.

Once you have the JAR files and library.xml in your temp directory, type this on a Windows machine:

java -classpath jooq-3.9.6.jar;jooq-meta-3.9.6.jar;jooq-codegen-3.9.6.jar;mysql-connector-java.jar;.
  org.jooq.util.GenerationTool library.xml

... or type this on a UNIX / Linux / Mac system (colons instead of semi-colons):

java -classpath jooq-3.9.6.jar:jooq-meta-3.9.6.jar:jooq-codegen-3.9.6.jar:mysql-connector-java.jar:.
  org.jooq.util.GenerationTool library.xml

Note: The GenerationTool class has been moved to org.jooq.codegen in jOOQ 3.11

Note: jOOQ will try loading the library.xml from your classpath. This is also why there is a trailing period (.) on the classpath. If the file cannot be found on the classpath, jOOQ will look on the file system from the current working directory.

Replace the filenames with your actual filenames. In this example, jOOQ 3.9.6 is being used. If everything has worked, you should see this in your console output:

Nov 1, 2011 7:25:06 PM org.jooq.impl.JooqLogger info
INFO: Initialising properties  : /library.xml
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Database parameters
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: ----------------------------------------------------------
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO:   dialect                : MYSQL
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO:   schema                 : library
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO:   target dir             : C:/workspace/MySQLTest/src
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO:   target package         : test.generated
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: ----------------------------------------------------------
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Emptying                 : C:/workspace/MySQLTest/src/test/generated
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Generating classes in    : C:/workspace/MySQLTest/src/test/generated
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Generating schema        : Library.java
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Schema generated         : Total: 122.18ms
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Sequences fetched        : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Tables fetched           : 5 (5 included, 0 excluded)
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Generating tables        : C:/workspace/MySQLTest/src/test/generated/tables
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: ARRAYs fetched           : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Enums fetched            : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: UDTs fetched             : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Generating table         : Author.java
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Tables generated         : Total: 680.464ms, +558.284ms
Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info
INFO: Generating Keys          : C:/workspace/MySQLTest/src/test/generated/tables
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Keys generated           : Total: 718.621ms, +38.157ms
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Generating records       : C:/workspace/MySQLTest/src/test/generated/tables/records
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Generating record        : AuthorRecord.java
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Table records generated  : Total: 782.545ms, +63.924ms
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Routines fetched         : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: Packages fetched         : 0 (0 included, 0 excluded)
Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info
INFO: GENERATION FINISHED!     : Total: 791.688ms, +9.143ms
 

3.5.1.4. Step 4: Connect to your database

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Let's just write a vanilla main class in the project containing the generated classes:

// For convenience, always static import your generated tables and jOOQ functions to decrease verbosity:
import static test.generated.Tables.*;
import static org.jooq.impl.DSL.*;

import java.sql.*;

public class Main {
    public static void main(String[] args) {
        String userName = "root";
        String password = "";
        String url = "jdbc:mysql://localhost:3306/library";

        // Connection is the only JDBC resource that we need
        // PreparedStatement and ResultSet are handled by jOOQ, internally
        try (Connection conn = DriverManager.getConnection(url, userName, password)) {
            // ...
        }

        // For the sake of this tutorial, let's keep exception handling simple
        catch (Exception e) {
            e.printStackTrace();
        }
    }
}

This is pretty standard code for establishing a MySQL connection.

 

3.5.1.5. Step 5: Querying

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Let's add a simple query constructed with jOOQ's query DSL:

DSLContext create = DSL.using(conn, SQLDialect.MYSQL);
Result<Record> result = create.select().from(AUTHOR).fetch();

First get an instance of DSLContext so we can write a simple SELECT query. We pass an instance of the MySQL connection to DSL. Note that the DSLContext doesn't close the connection. We'll have to do that ourselves.

We then use jOOQ's query DSL to return an instance of Result. We'll be using this result in the next step.

 

3.5.1.6. Step 6: Iterating

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

After the line where we retrieve the results, let's iterate over the results and print out the data:

for (Record r : result) {
    Integer id = r.getValue(AUTHOR.ID);
    String firstName = r.getValue(AUTHOR.FIRST_NAME);
    String lastName = r.getValue(AUTHOR.LAST_NAME);

    System.out.println("ID: " + id + " first name: " + firstName + " last name: " + lastName);
}

The full program should now look like this:

package test;

// For convenience, always static import your generated tables and
// jOOQ functions to decrease verbosity:
import static test.generated.Tables.*;
import static org.jooq.impl.DSL.*;

import java.sql.*;

import org.jooq.*;
import org.jooq.impl.*;

public class Main {

    /**
     * @param args
     */
    public static void main(String[] args) {
        String userName = "root";
        String password = "";
        String url = "jdbc:mysql://localhost:3306/library";

        // Connection is the only JDBC resource that we need
        // PreparedStatement and ResultSet are handled by jOOQ, internally
        try (Connection conn = DriverManager.getConnection(url, userName, password)) {
            DSLContext create = DSL.using(conn, SQLDialect.MYSQL);
            Result<Record> result = create.select().from(AUTHOR).fetch();

            for (Record r : result) {
                Integer id = r.getValue(AUTHOR.ID);
                String firstName = r.getValue(AUTHOR.FIRST_NAME);
                String lastName = r.getValue(AUTHOR.LAST_NAME);

                System.out.println("ID: " + id + " first name: " + firstName + " last name: " + lastName);
            }
        }

        // For the sake of this tutorial, let's keep exception handling simple
        catch (Exception e) {
            e.printStackTrace();
        }
    }
}
 

3.5.1.7. Step 7: Explore!

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ has grown to be a comprehensive SQL library. For more information, please consider the documentation:
https://www.jooq.org/learn

... explore the Javadoc:
https://www.jooq.org/javadoc/latest/

... or join the news group:
https://groups.google.com/forum/#!forum/jooq-user

This tutorial is the courtesy of Ikai Lan. See the original source here:
https://ikaisays.com/2011/11/01/getting-started-with-jooq-a-tutorial/

 

3.5.2. Using jOOQ with Flyway

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Flyway - Database Migrations Made EasyWhen performing database migrations, we at Data Geekery recommend using jOOQ with Flyway - Database Migrations Made Easy. In this chapter, we're going to look into a simple way to get started with the two frameworks.

Philosophy

There are a variety of ways how jOOQ and Flyway could interact with each other in various development setups. In this tutorial we're going to show just one variant of such framework team play - a variant that we find particularly compelling for most use cases.

The general philosophy behind the following approach can be summarised as this:

  • 1. Database increment
  • 2. Database migration
  • 3. Code re-generation
  • 4. Development

The four steps above can be repeated time and again, every time you need to modify something in your database. More concretely, let's consider:

  • 1. Database increment - You need a new column in your database, so you write the necessary DDL in a Flyway script
  • 2. Database migration - This Flyway script is now part of your deliverable, which you can share with all developers who can migrate their databases with it, the next time they check out your change
  • 3. Code re-generation - Once the database is migrated, you regenerate all jOOQ artefacts (see code generation), locally
  • 4. Development - You continue developing your business logic, writing code against the updated, generated database schema

Maven Project Configuration - Properties

The following properties are defined in our pom.xml, to be able to reuse them between plugin configurations:

<properties>
    <db.url>jdbc:h2:~/flyway-test</db.url>
    <db.username>sa</db.username>
</properties>

0. Maven Project Configuration - Dependencies

While jOOQ and Flyway could be used in standalone migration scripts, in this tutorial, we'll be using Maven for the standard project setup. You will also find the source code of this tutorial on GitHub at https://github.com/jOOQ/jOOQ/tree/main/jOOQ-examples/jOOQ-flyway-example, and the full pom.xml file here.

These are the dependencies that we're using in our Maven configuration:

<!-- We'll add the latest version of jOOQ and our JDBC driver - in this case H2 -->
<dependency>
    <!-- Use org.jooq            for the Open Source Edition
             org.jooq.pro        for commercial editions,
             org.jooq.pro-java-8 for commercial editions with Java 8 support,
             org.jooq.pro-java-6 for commercial editions with Java 6 support,
             org.jooq.trial      for the free trial edition

         Note: Only the Open Source Edition is hosted on Maven Central.
               Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org -->
    <groupId>org.jooq</groupId>
    <artifactId>jooq</artifactId>
    <version>3.9.6</version>
</dependency>
<dependency>
    <groupId>com.h2database</groupId>
    <artifactId>h2</artifactId>
    <version>1.4.197</version>
</dependency>

<!-- For improved logging, we'll be using log4j via slf4j to see what's going on during migration and code generation -->
<dependency>
    <groupId>org.apache.logging.log4j</groupId>
    <artifactId>log4j-slf4j-impl</artifactId>
    <version>2.11.0</version>
</dependency>

<!-- To ensure our code is working, we're using JUnit -->
<dependency>
    <groupId>junit</groupId>
    <artifactId>junit</artifactId>
    <version>4.11</version>
    <scope>test</scope>
</dependency>

0. Maven Project Configuration - Plugins

After the dependencies, let's simply add the Flyway and jOOQ Maven plugins like so. The Flyway plugin:

<plugin>
    <groupId>org.flywaydb</groupId>
    <artifactId>flyway-maven-plugin</artifactId>
    <version>3.0</version>

    <!-- Note that we're executing the Flyway plugin in the "generate-sources" phase -->
    <executions>
        <execution>
            <phase>generate-sources</phase>
            <goals>
                <goal>migrate</goal>
            </goals>
        </execution>
    </executions>

    <!-- Note that we need to prefix the db/migration path with filesystem: to prevent Flyway
         from looking for our migration scripts only on the classpath -->
    <configuration>
        <url>${db.url}</url>
        <user>${db.username}</user>
        <locations>
            <location>filesystem:src/main/resources/db/migration</location>
        </locations>
    </configuration>
</plugin>

The above Flyway Maven plugin configuration will read and execute all database migration scripts from src/main/resources/db/migration prior to compiling Java source code. While the official Flyway documentation may suggest that migrations be done in the compile phase, the jOOQ code generator relies on such migrations having been done prior to code generation.

After the Flyway plugin, we'll add the jOOQ Maven Plugin. For more details, please refer to the manual's section about the code generation configuration.

<plugin>
    <!-- Use org.jooq            for the Open Source Edition
             org.jooq.pro        for commercial editions,
             org.jooq.pro-java-8 for commercial editions with Java 8 support,
             org.jooq.pro-java-6 for commercial editions with Java 6 support,
             org.jooq.trial      for the free trial edition

         Note: Only the Open Source Edition is hosted on Maven Central.
               Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org -->
    <groupId>org.jooq</groupId>
    <artifactId>jooq-codegen-maven</artifactId>
    <version>${org.jooq.version}</version>

    <!-- The jOOQ code generation plugin is also executed in the generate-sources phase, prior to compilation -->
    <executions>
        <execution>
            <phase>generate-sources</phase>
            <goals>
                <goal>generate</goal>
            </goals>
        </execution>
    </executions>

    <!-- This is a minimal working configuration. See the manual's section about the code generator for more details -->
    <configuration>
        <jdbc>
            <url>${db.url}</url>
            <user>${db.username}</user>
        </jdbc>
        <generator>
            <database>
                <includes>.*</includes>
                <inputSchema>FLYWAY_TEST</inputSchema>
            </database>
            <target>
                <packageName>org.jooq.example.flyway.db.h2</packageName>
                <directory>target/generated-sources/jooq-h2</directory>
            </target>
        </generator>
    </configuration>
</plugin>

This configuration will now read the FLYWAY_TEST schema and reverse-engineer it into the target/generated-sources/jooq-h2 directory, and within that, into the org.jooq.example.flyway.db.h2 package.

1. Database increments

Now, when we start developing our database. For that, we'll create database increment scripts, which we put into the src/main/resources/db/migration directory, as previously configured for the Flyway plugin. We'll add these files:

  • V1__initialise_database.sql
  • V2__create_author_table.sql
  • V3__create_book_table_and_records.sql

These three scripts model our schema versions 1-3 (note the capital V!). Here are the scripts' contents

-- V1__initialise_database.sql
DROP SCHEMA flyway_test IF EXISTS;

CREATE SCHEMA flyway_test;
-- V2__create_author_table.sql
CREATE SEQUENCE flyway_test.s_author_id START WITH 1;

CREATE TABLE flyway_test.author (
  id INT NOT NULL,
  first_name VARCHAR(50),
  last_name VARCHAR(50) NOT NULL,
  date_of_birth DATE,
  year_of_birth INT,
  address VARCHAR(50),

  CONSTRAINT pk_author PRIMARY KEY (ID)
);
-- V3__create_book_table_and_records.sql
CREATE TABLE flyway_test.book (
  id INT NOT NULL,
  author_id INT NOT NULL,
  title VARCHAR(400) NOT NULL,

  CONSTRAINT pk_book PRIMARY KEY (id),
  CONSTRAINT fk_book_author_id FOREIGN KEY (author_id) REFERENCES flyway_test.author(id)
);


INSERT INTO flyway_test.author VALUES (next value for flyway_test.s_author_id, 'George', 'Orwell', '1903-06-25', 1903, null);
INSERT INTO flyway_test.author VALUES (next value for flyway_test.s_author_id, 'Paulo', 'Coelho', '1947-08-24', 1947, null);

INSERT INTO flyway_test.book VALUES (1, 1, '1984');
INSERT INTO flyway_test.book VALUES (2, 1, 'Animal Farm');
INSERT INTO flyway_test.book VALUES (3, 2, 'O Alquimista');
INSERT INTO flyway_test.book VALUES (4, 2, 'Brida');

2. Database migration and 3. Code regeneration

The above three scripts are picked up by Flyway and executed in the order of the versions. This can be seen very simply by executing:

mvn clean install

And then observing the log output from Flyway...

[INFO] --- flyway-maven-plugin:3.0:migrate (default) @ jooq-flyway-example ---
[INFO] Database: jdbc:h2:~/flyway-test (H2 1.4)
[INFO] Validated 3 migrations (execution time 00:00.004s)
[INFO] Creating Metadata table: "PUBLIC"."schema_version"
[INFO] Current version of schema "PUBLIC": << Empty Schema >>
[INFO] Migrating schema "PUBLIC" to version 1
[INFO] Migrating schema "PUBLIC" to version 2
[INFO] Migrating schema "PUBLIC" to version 3
[INFO] Successfully applied 3 migrations to schema "PUBLIC" (execution time 00:00.073s).

... and from jOOQ on the console:

[INFO] --- jooq-codegen-maven:3.9.6:generate (default) @ jooq-flyway-example ---
[INFO] --- jooq-codegen-maven:3.9.6:generate (default) @ jooq-flyway-example ---
[INFO] Using this configuration:
...
[INFO] Generating schemata      : Total: 1
[INFO] Generating schema        : FlywayTest.java
[INFO] ----------------------------------------------------------
[....]
[INFO] GENERATION FINISHED!     : Total: 337.576ms, +4.299ms

4. Development

Note that all of the previous steps are executed automatically, every time someone adds new migration scripts to the Maven module. For instance, a team member might have committed a new migration script, you check it out, rebuild and get the latest jOOQ-generated sources for your own development or integration-test database.

Now, that these steps are done, you can proceed writing your database queries. Imagine the following test case

import org.jooq.Result;
import org.jooq.impl.DSL;
import org.junit.Test;

import java.sql.DriverManager;

import static java.util.Arrays.asList;
import static org.jooq.example.flyway.db.h2.Tables.*;
import static org.junit.Assert.assertEquals;

public class AfterMigrationTest {

    @Test
    public void testQueryingAfterMigration() throws Exception {
        try (Connection c = DriverManager.getConnection("jdbc:h2:~/flyway-test", "sa", "")) {
            Result<?> result =
            DSL.using(c)
               .select(
                   AUTHOR.FIRST_NAME,
                   AUTHOR.LAST_NAME,
                   BOOK.ID,
                   BOOK.TITLE
               )
               .from(AUTHOR)
               .join(BOOK)
               .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
               .orderBy(BOOK.ID.asc())
               .fetch();

            assertEquals(4, result.size());
            assertEquals(asList(1, 2, 3, 4), result.getValues(BOOK.ID));
        }
    }
}

Reiterate

The power of this approach becomes clear once you start performing database modifications this way. Let's assume that the French guy on our team prefers to have things his way:

-- V4__le_french.sql
ALTER TABLE flyway_test.book ALTER COLUMN title RENAME TO le_titre;

They check it in, you check out the new database migration script, run

mvn clean install

And then observing the log output:

[INFO] --- flyway-maven-plugin:3.0:migrate (default) @ jooq-flyway-example ---
[INFO] --- flyway-maven-plugin:3.0:migrate (default) @ jooq-flyway-example ---
[INFO] Database: jdbc:h2:~/flyway-test (H2 1.4)
[INFO] Validated 4 migrations (execution time 00:00.005s)
[INFO] Current version of schema "PUBLIC": 3
[INFO] Migrating schema "PUBLIC" to version 4
[INFO] Successfully applied 1 migration to schema "PUBLIC" (execution time 00:00.016s).

So far so good, but later on:

[ERROR] COMPILATION ERROR :
[INFO] -------------------------------------------------------------
[ERROR] C:\...\jOOQ-flyway-example\src\test\java\AfterMigrationTest.java:[24,19] error: cannot find symbol
[INFO] 1 error

When we go back to our Java integration test, we can immediately see that the TITLE column is still being referenced, but it no longer exists:

public class AfterMigrationTest {

    @Test
    public void testQueryingAfterMigration() throws Exception {
        try (Connection c = DriverManager.getConnection("jdbc:h2:~/flyway-test", "sa", "")) {
            Result<?> result =
            DSL.using(c)
                .select(
                    AUTHOR.FIRST_NAME,
                    AUTHOR.LAST_NAME,
                    BOOK.ID,
                    BOOK.TITLE
                    //   ^^^^^ This column no longer exists. We'll have to rename it to LE_TITRE
                )
                .from(AUTHOR)
                .join(BOOK)
                .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
                .orderBy(BOOK.ID.asc())
                .fetch();

            assertEquals(4, result.size());
            assertEquals(asList(1, 2, 3, 4), result.getValues(BOOK.ID));
        }
    }
}

Automation

The above steps can be automated in your build using another third party called testcontainers. Please look at this article here for examples on how to do that: https://blog.jooq.org/using-testcontainers-to-generate-jooq-code/

Conclusion

This tutorial shows very easily how you can build a rock-solid development process using Flyway and jOOQ to prevent SQL-related errors very early in your development lifecycle - immediately at compile time, rather than in production!

Please, visit the Flyway website for more information about Flyway.

 

3.5.3. Using jOOQ with jbang

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jbang allows for quickly working with all sorts of Java libraries without the hassle of setting up environments, dependencies, etc. This catalog allows for using jOOQ's code generator right away on an existing database.

For more information on jbang, see:

An example

In a shell, type

git clone https://github.com/jOOQ/jbang-example
cd jbang-example
jbang Example.java

In order to re-generate the example code, e.g. when your schema changes, just type:

jbang codegen@jooq db.xml

If you prefer working with a pre-existing database, just edit the db.xml file and point it to your database. Add the JDBC driver dependency like this:

jbang --deps org.postgresql:postgresql:RELEASE codegen@jooq db.xml

To override the jOOQ version from the default RELEASE to a specific version, use

jbang -Djooq.version=<version> codegen@jooq db.xml
 

3.6. jOOQ and Java 8

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Java 8 has introduced a great set of enhancements, among which lambda expressions and the new java.util.stream.Stream. These new constructs align very well with jOOQ's fluent API as can be seen in the following examples:

jOOQ and lambda expressions

jOOQ's RecordMapper API is fully Java-8-ready, which basically means that it is a SAM (Single Abstract Method) type, which can be instanciated using a lambda expression. Consider this example:

try (Connection c = getConnection()) {
    String sql = "select schema_name, is_default " +
                 "from information_schema.schemata " +
                 "order by schema_name";

    DSL.using(c)
       .fetch(sql)

       // We can use lambda expressions to map jOOQ Records
       .map(rs -> new Schema(
           rs.getValue("SCHEMA_NAME", String.class),
           rs.getValue("IS_DEFAULT", boolean.class)
       ))

       // ... and then profit from the new Collection methods
       .forEach(System.out::println);
}

The above example shows how jOOQ's Result.map() method can receive a lambda expression that implements RecordMapper to map from jOOQ Records to your custom types.

jOOQ and the Streams API

jOOQ's Result type extends java.util.List, which opens up access to a variety of new Java features in Java 8. The following example shows how easy it is to transform a jOOQ Result containing INFORMATION_SCHEMA meta data to produce DDL statements:

DSL.using(c)
   .select(
       COLUMNS.TABLE_NAME,
       COLUMNS.COLUMN_NAME,
       COLUMNS.TYPE_NAME
   )
   .from(COLUMNS)
   .orderBy(
       COLUMNS.TABLE_CATALOG,
       COLUMNS.TABLE_SCHEMA,
       COLUMNS.TABLE_NAME,
       COLUMNS.ORDINAL_POSITION
   )
   .fetch()  // jOOQ ends here
   .stream() // JDK 8 Streams start here
   .collect(groupingBy(
       r -> r.getValue(COLUMNS.TABLE_NAME),
       LinkedHashMap::new,
       mapping(
           r -> new Column(
               r.getValue(COLUMNS.COLUMN_NAME),
               r.getValue(COLUMNS.TYPE_NAME)
           ),
           toList()
       )
   ))
   .forEach(
       (table, columns) -> {
            // Just emit a CREATE TABLE statement
            System.out.println(
                "CREATE TABLE " + table + " (");

            // Map each "Column" type into a String
            // containing the column specification,
            // and join them using comma and
            // newline. Done!
            System.out.println(
                columns.stream()
                       .map(col -> "  " + col.name +
                                    " " + col.type)
                       .collect(Collectors.joining(",\n"))
            );

           System.out.println(");");
       }
   );

The above example is explained more in depth in this blog post: https://blog.jooq.org/java-8-friday-no-more-need-for-orms/. For more information about Java 8, consider these resources:

 

3.7. jOOQ and JavaFX

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

One of the major improvements of Java 8 is the introduction of JavaFX into the JavaSE. With jOOQ and Java 8 Streams and lambdas, it is now very easy and idiomatic to transform SQL results into JavaFX XYChart.Series or other, related objects:

Creating a bar chart from a jOOQ Result

As we've seen in the previous section about jOOQ and Java 8, jOOQ integrates seamlessly with Java 8's Streams API. The fluent style can be maintained throughout the data transformation chain.

In this example, we're going to use Open Data from the world bank to show a comparison of countries GDP and debts:

DROP SCHEMA IF EXISTS world;

CREATE SCHEMA world;

CREATE TABLE world.countries (
  code CHAR(2) NOT NULL,
  year INT NOT NULL,
  gdp_per_capita DECIMAL(10, 2) NOT NULL,
  govt_debt DECIMAL(10, 2) NOT NULL
);

INSERT INTO world.countries
VALUES ('CA', 2009, 40764, 51.3),
       ('CA', 2010, 47465, 51.4),
       ('CA', 2011, 51791, 52.5),
       ('CA', 2012, 52409, 53.5),
       ('DE', 2009, 40270, 47.6),
       ('DE', 2010, 40408, 55.5),
       ('DE', 2011, 44355, 55.1),
       ('DE', 2012, 42598, 56.9),
       ('FR', 2009, 40488, 85.0),
       ('FR', 2010, 39448, 89.2),
       ('FR', 2011, 42578, 93.2),
       ('FR', 2012, 39759,103.8),
       ('GB', 2009, 35455,121.3),
       ('GB', 2010, 36573, 85.2),
       ('GB', 2011, 38927, 99.6),
       ('GB', 2012, 38649,103.2),
       ('IT', 2009, 35724,121.3),
       ('IT', 2010, 34673,119.9),
       ('IT', 2011, 36988,113.0),
       ('IT', 2012, 33814,131.1),
       ('JP', 2009, 39473,166.8),
       ('JP', 2010, 43118,174.8),
       ('JP', 2011, 46204,189.5),
       ('JP', 2012, 46548,196.5),
       ('RU', 2009,  8616,  8.7),
       ('RU', 2010, 10710,  9.1),
       ('RU', 2011, 13324,  9.3),
       ('RU', 2012, 14091,  9.4),
       ('US', 2009, 46999, 76.3),
       ('US', 2010, 48358, 85.6),
       ('US', 2011, 49855, 90.1),
       ('US', 2012, 51755, 93.8);

Once this data is set up (e.g. in an H2 or PostgreSQL database), we'll run jOOQ's code generator and implement the following code to display our chart:

CategoryAxis xAxis = new CategoryAxis();
NumberAxis yAxis = new NumberAxis();
xAxis.setLabel("Country");
yAxis.setLabel("% of GDP");

BarChart<String, Number> bc = new BarChart<String, Number>(xAxis, yAxis);
bc.setTitle("Government Debt");
bc.getData().addAll(

    // SQL data transformation, executed in the database
    // -------------------------------------------------
    DSL.using(connection)
       .select(
           COUNTRIES.YEAR,
           COUNTRIES.CODE,
           COUNTRIES.GOVT_DEBT)
       .from(COUNTRIES)
       .join(
           table(
               select(COUNTRIES.CODE, avg(COUNTRIES.GOVT_DEBT).as("avg"))
               .from(COUNTRIES)
               .groupBy(COUNTRIES.CODE)
           ).as("c1")
       )
       .on(COUNTRIES.CODE.eq(field(name("c1", COUNTRIES.CODE.getName()), String.class)))

       // order countries by their average projected value
       .orderBy(
           field(name("avg")),
           COUNTRIES.CODE,
           COUNTRIES.YEAR)

       // The result produced by the above statement looks like this:
       // +----+----+---------+
       // |year|code|govt_debt|
       // +----+----+---------+
       // |2009|RU  |     8.70|
       // |2010|RU  |     9.10|
       // |2011|RU  |     9.30|
       // |2012|RU  |     9.40|
       // |2009|CA  |    51.30|
       // +----+----+---------+

    // Java data transformation, executed in application memory
    // --------------------------------------------------------

       // Group results by year, keeping sort order in place
       .fetchGroups(COUNTRIES.YEAR)

       // Stream<Entry<Integer, Result<Record3<BigDecimal, String, Integer>>>>
       .entrySet()
       .stream()

       // Map each entry into a { Year -> Projected value } series
       .map(entry -> new XYChart.Series<>(
           entry.getKey().toString(),
           observableArrayList(

               // Map each country record into a chart Data object
               entry.getValue()
                    .map(country -> new XYChart.Data<String, Number>(
                         country.getValue(COUNTRIES.CODE),
                         country.getValue(COUNTRIES.GOVT_DEBT)
                    ))
           )
       ))
       .collect(toList())
);

The above example uses basic SQL-92 syntax where the countries are ordered using aggregate information from a derived table, which is supported in all databases. If you're using a database that supports window functions, e.g. PostgreSQL or any commercial database, you could have also written a simpler query like this:00

DSL.using(connection)
   .select(
       COUNTRIES.YEAR,
       COUNTRIES.CODE,
       COUNTRIES.GOVT_DEBT)
   .from(COUNTRIES)

   // order countries by their average projected value
   .orderBy(
       DSL.avg(COUNTRIES.GOVT_DEBT).over(partitionBy(COUNTRIES.CODE)),
       COUNTRIES.CODE,
       COUNTRIES.YEAR)
   .fetch()
   ;

return bc;

When executed, we'll get nice-looking bar charts like these:
jOOQ and JavaFX Example

The complete example can be downloaded and run from GitHub:
https://github.com/jOOQ/jOOQ/tree/main/jOOQ-examples/jOOQ-javafx-example

 

3.8. jOOQ and Nashorn

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

With Java 8 and the new built-in JavaScript engine Nashorn, a whole new ecosystem of software can finally make easy use of jOOQ in server-side JavaScript. A very simple example can be seen here:

// Let's assume these objects were generated
// by the jOOQ source code generator
var Tables = Java.type("org.jooq.db.h2.information_schema.Tables");
var t = Tables.TABLES;
var c = Tables.COLUMNS;

// This is the equivalent of Java's static imports
var count = DSL.count;
var row = DSL.row;

// We can now execute the following query:
print(
    DSL.using(conn)
       .select(
           t.TABLE_SCHEMA,
           t.TABLE_NAME,
           c.COLUMN_NAME)
       .from(t)
       .join(c)
       .on(row(t.TABLE_SCHEMA, t.TABLE_NAME)
           .eq(c.TABLE_SCHEMA, c.TABLE_NAME))
       .orderBy(
           t.TABLE_SCHEMA.asc(),
           t.TABLE_NAME.asc(),
           c.ORDINAL_POSITION.asc())
       .fetch()
);
 

3.9. jOOQ and Scala

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

As any other library, jOOQ can be easily used in Scala, taking advantage of the many Scala language features such as for example:

  • Optional "." to dereference methods from expressions
  • Optional "(" and ")" to delimit method argument lists
  • Optional ";" at the end of a Scala statement
  • Type inference using "var" and "val" keywords
  • Lambda expressions and for-comprehension syntax for record iteration and data type conversion

But jOOQ also leverages other useful Scala features, such as

  • implicit defs for operator overloading
  • Scala Macros (soon to come)

All of the above heavily improve jOOQ's querying DSL API experience for Scala developers.

A short example jOOQ application in Scala might look like this:

import collection.JavaConversions._                                  // Import implicit defs for iteration over org.jooq.Result
                                                                     //
import java.sql.DriverManager                                        //
                                                                     //
import org.jooq._                                                    //
import org.jooq.impl._                                               //
import org.jooq.impl.DSL._                                           //
import org.jooq.examples.scala.h2.Tables._                           //
import org.jooq.scalaextensions.Conversions._                        // Import implicit defs for overloaded jOOQ/SQL operators
                                                                     //
object Test {                                                        //
  def main(args: Array[String]): Unit = {                            //
    val c = DriverManager.getConnection("jdbc:h2:~/test", "sa", ""); // Standard JDBC connection
    val e = DSL.using(c, SQLDialect.H2);                             //
    val x = AUTHOR as "x"                                            // SQL-esque table aliasing
                                                                     //
    for (r <- e                                                      // Iteration over Result. "r" is an org.jooq.Record3
        select (                                                     //
          BOOK.ID * BOOK.AUTHOR_ID,                                  // Using the overloaded "*" operator
          BOOK.ID + BOOK.AUTHOR_ID * 3 + 4,                          // Using the overloaded "+" operator
          BOOK.TITLE || " abc" || " xy"                              // Using the overloaded "||" operator
        )                                                            //
        from BOOK                                                    // No need to use parentheses or "." here
        leftOuterJoin (                                              //
          select (x.ID, x.YEAR_OF_BIRTH)                             // Dereference fields from aliased table
          from x                                                     //
          limit 1                                                    //
          asTable x.getName()                                        //
        )                                                            //
        on BOOK.AUTHOR_ID === x.ID                                   // Using the overloaded "===" operator
        where (BOOK.ID <> 2)                                         // Using the olerloaded "<>" operator
        or (BOOK.TITLE in ("O Alquimista", "Brida"))                 // Neat IN predicate expression
        fetch                                                        //
    ) {                                                              //
      println(r)                                                     //
    }                                                                //
  }                                                                  //
}

For more details about jOOQ's Scala integration, please refer to the manual's section about SQL building with Scala.

 

3.10. jOOQ and Groovy

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

As any other library, jOOQ can be easily used in Groovy, taking advantage of the many Groovy language features such as for example:

  • Optional ";" at the end of a Groovy statement
  • Type inference for local variables

A short example jOOQ application in Groovy might look like this:

package org.jooq.groovy

import static org.jooq.impl.DSL.*
import static org.jooq.groovy.example.h2.Tables.*

import groovy.sql.Sql
import org.jooq.*
import org.jooq.impl.DSL

sql = Sql.newInstance('jdbc:h2:~/groovy-test', 'sa', '', 'org.h2.Driver');

a = AUTHOR.as("a");
b = BOOK.as("b")

DSL.using(sql.connection)
   .select(a.FIRST_NAME, a.LAST_NAME, b.TITLE)
   .from(a)
   .join(b).on(a.ID.eq(b.AUTHOR_ID))
   .fetchInto ({
       r -> println(
           "${r.getValue(a.FIRST_NAME)} " +
           "${r.getValue(a.LAST_NAME)} " +
           "has written ${r.getValue(b.TITLE)}"
       )
   } as RecordHandler)

Note that while Groovy supports some means of operator overloading, we think that these means should be avoided in a jOOQ integration. For instance, a + b in Groovy maps to a formal a.plus(b) method invocation, and jOOQ provides the required synonyms in its API to help you write such expressions. Nonetheless, Groovy only offers little typesafety, and as such, operator overloading can lead to many runtime issues.

Another caveat of Groovy operator overloading is the fact that operators such as == or >= map to a.equals(b), a.compareTo(b) == 0, a.compareTo(b) >= 0 respectively. This behaviour does not make sense in a fluent API such as jOOQ.

 

3.11. jOOQ and Kotlin

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

As any other library, jOOQ can be easily used in Kotlin, taking advantage of the many Kotlin language features such as for example:

  • Optional ";" at the end of a Kotlin statement
  • Type inference for local variables

A short example jOOQ application in Kotlin might look like this:

package org.jooq.example.kotlin

import java.util.Properties

import org.jooq.*
import org.jooq.impl.DSL
import org.jooq.impl.DSL.*

import org.jooq.example.db.h2.Tables.*

fun main(args: Array<String>) {

    val properties = Properties();
    properties.load(Properties::class.java.getResourceAsStream("/config.properties"));

    DSL.using(
        properties.getProperty("db.url"),
        properties.getProperty("db.username"),
        properties.getProperty("db.password")
    ).use { ctx ->
        val a = AUTHOR
        val b = BOOK

        ctx.select(a.FIRST_NAME, a.LAST_NAME, b.TITLE)
           .from(a)
           .join(b).on(a.ID.eq(b.AUTHOR_ID))
           .orderBy(1, 2, 3)
           .forEach {
               println("${it[b.TITLE]} by ${it[a.FIRST_NAME]} ${it[a.LAST_NAME]}")
           }
    }
}

Note that Kotlin supports some means of operator overloading. For instance, a + b in Kotlin maps to a formal a.plus(b) method invocation, and jOOQ provides the required synonyms in its API to help you write such expressions.

One particularly nice language feature is the fact that [square brackets] allow for accessing any object's contents via get() and set() methods. Instead of using the above value1(), value2(), and value3() methods, we could also iterate as such:

        ctx.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE)
           .from(AUTHOR)
           .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
           .orderBy(1, 2, 3)
           .forEach {
               println("${it[BOOK.TITLE]} by ${it[AUTHOR.FIRST_NAME]} ${it[AUTHOR.LAST_NAME]}")
               // Notice:   ^^^^^^^^^^^^         ^^^^^^^^^^^^^^^^^^^      ^^^^^^^^^^^^^^^^^^
           }

A caveat of Kotlin operator overloading is the fact that operators such as == or >= map to a.equals(b), a.compareTo(b) == 0, a.compareTo(b) >= 0 respectively. This behaviour does not make sense in a fluent API such as jOOQ.

 

3.12. jOOQ and NoSQL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ users often get excited about jOOQ's intuitive API and would then wish for NoSQL support.

There are a variety of NoSQL databases that implement some sort of proprietary query language. Some of these query languages even look like SQL. Examples are JCR-SQL2, CQL (Cassandra Query Language), Cypher (Neo4j's Query Language), and many more.

Mapping the jOOQ API onto these alternative query languages would be a very poor fit and a leaky abstraction. We believe in the power and expressivity of the SQL standard and its various dialects. Databases that extend this standard too much, or implement it not thoroughly enough are often not suitable targets for jOOQ. It would be better to build a new, dedicated API for just that one particular query language.

jOOQ is about SQL, and about SQL alone. Read more about our visions in the manual's preface.

 

3.13. jOOQ and JPA

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Just because you're using jOOQ doesn't mean you have to use it for everything!

When introducing jOOQ into an existing application that uses JPA, the common question is always: "Should we replace JPA by jOOQ?" and "How do we proceed doing that?"

Beware that jOOQ is not a replacement for JPA. Think of jOOQ as a complement. JPA (and ORMs in general) try to solve the object graph persistence problem. In short, this problem is about

  • Loading an entity graph into client memory from a database
  • Manipulating that graph in the client
  • Storing the modification back to the database

As the above graph gets more complex, a lot of tricky questions arise like:

  • What's the optimal order of SQL DML operations for loading and storing entities?
  • How can we batch the commands more efficiently?
  • How can we keep the transaction footprint as low as possible without compromising on ACID?
  • How can we implement optimistic locking?

jOOQ only has some of the answers.

While jOOQ does offer updatable records that help running simple CRUD, a batch API, optimistic locking capabilities, jOOQ mainly focuses on executing actual SQL statements.

SQL is the preferred language of database interaction, when any of the following are given:

  • You run reports and analytics on large data sets directly in the database
  • You import / export data using ETL
  • You run complex business logic as SQL queries

Whenever SQL is a good fit, jOOQ is a good fit. Whenever you're operating and persisting the object graph, JPA is a good fit.

And sometimes, it's best to combine both

 

3.14. Build your own

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In order to build jOOQ (Open Source Edition) yourself, please download the sources from https://github.com/jOOQ/jOOQ and use Maven to build jOOQ, preferably in Eclipse. The jOOQ Open Source Edition requires Java 8+ to compile and run. The commercial jOOQ Editions require Java 8+ or Java 6+ to compile and run, depending on the distribution.

Some useful hints to build jOOQ yourself:

  • Get the latest version of Git or EGit
  • Get the latest version of Maven or M2E
  • Check out the jOOQ sources from https://github.com/jOOQ/jOOQ
  • Optionally, import Maven artefacts into an Eclipse workspace using the following command (see the maven-eclipse-plugin documentation for details):
    • mvn eclipse:eclipse
  • Build the jooq-parent artefact by using any of these commands:
    • mvn clean package
      create .jar files in ${project.build.directory}
    • mvn clean install
      install the .jar files in your local repository (e.g. ~/.m2)
    • mvn clean {goal} -Dmaven.test.skip=true
      don't run unit tests when building artefacts
 

3.15. jOOQ and backwards-compatibility

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Semantic versioning

jOOQ's understanding of backwards compatibility is inspired by the rules of semantic versioning according to https://semver.org. Those rules impose a versioning scheme [X].[Y].[Z] that can be summarised as follows:

  • If a patch release includes bugfixes, performance improvements and API-irrelevant new features, [Z] is incremented by one.
  • If a minor release includes backwards-compatible, API-relevant new features, [Y] is incremented by one and [Z] is reset to zero.
  • If a major release includes backwards-incompatible, API-relevant new features, [X] is incremented by one and [Y], [Z] are reset to zero.

jOOQ's understanding of backwards-compatibility

Backwards-compatibility is important to jOOQ. You've chosen jOOQ as a strategic SQL engine and you don't want your SQL to break.

However, there are some elements of API evolution that would be considered backwards-incompatible in other APIs, but not in jOOQ. As discussed later on in the section about jOOQ's query DSL API, much of jOOQ's API is indeed an internal domain-specific language implemented mostly using Java interfaces. Adding language elements to these interfaces means any of these actions:

  • Adding methods to the interface
  • Overloading methods for convenience
  • Changing the type hierarchy of interfaces (including raw type or binary compatibility implications)

It becomes obvious that it would be impossible to add new language elements (e.g. new SQL functions, new SELECT clauses) to the API without breaking any client code that actually implements those interfaces. Hence, the following rules should be observed:

  • jOOQ's DSL interfaces should not be implemented by client code! Extend only those extension points that are explicitly documented as "extendable" (e.g. custom QueryParts).
  • Generated code implements such interfaces and extends internal classes, and as such is recommended to be re-generated with a matching code generator version every time the runtime library is upgraded.
  • Binary compatibility can be expected from patch releases, but not from minor releases as it is not practical to maintain binary compatibility in an internal DSL.
  • Source compatibility can be expected from patch and minor releases, the exception being raw type compatibility (see #11879), and rare exceptions where API design is clearly lacking.
  • Behavioural compatibility can be expected from patch and minor releases.
  • Any jOOQ SPI XYZ that is meant to be implemented ships with a DefaultXYZ or AbstractXYZ, which can be used safely as a default implementation.

jOOQ-codegen and jOOQ-meta

While a reasonable amount of care is spent to maintain these two modules under the rules of semantic versioning, it may well be that minor releases introduce backwards-incompatible changes. This will be announced in the respective release notes and should be the exception.

 

4. SQL building

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

SQL is a declarative language that is hard to integrate into procedural, object-oriented, functional or any other type of programming languages. jOOQ's philosophy is to give SQL the credit it deserves and integrate SQL itself as an "internal domain specific language" directly into Java.

With this philosophy in mind, SQL building is the main feature of jOOQ. All other features (such as SQL execution and code generation) are mere convenience built on top of jOOQ's SQL building capabilities.

This section explains all about the various syntax elements involved with jOOQ's SQL building capabilities. For a complete overview of all syntax elements, please refer to the manual's sections about SQL to DSL mapping rules.

 

4.1. The query DSL type

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ exposes a lot of interfaces and hides most implementation facts from client code. The reasons for this are:

  • Interface-driven design. This allows for modelling queries in a fluent API most efficiently
  • Reduction of complexity for client code.
  • API guarantee. You only depend on the exposed interfaces, not concrete (potentially dialect-specific) implementations.

The org.jooq.impl.DSL class is the main class from where you will create all jOOQ objects. It serves as a static factory for table expressions, column expressions (or "fields"), conditional expressions and many other QueryParts.

The static query DSL API

With jOOQ 2.0, static factory methods have been introduced in order to make client code look more like SQL. Ideally, when working with jOOQ, you will simply static import all methods from the DSL class:

import static org.jooq.impl.DSL.*;

Note, that when working with Eclipse, you could also add the DSL to your favourites. This will allow to access functions even more fluently:

concat(trim(FIRST_NAME), trim(LAST_NAME));

// ... which is in fact the same as:
DSL.concat(DSL.trim(FIRST_NAME), DSL.trim(LAST_NAME));
 

4.1.1. DSL subclasses

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

There are a couple of subclasses for the general query DSL. Each SQL dialect has its own dialect-specific DSL. For instance, if you're only using the MySQL dialect, you can choose to reference the MySQLDSL instead of the standard DSL:

The advantage of referencing a dialect-specific DSL lies in the fact that you have access to more proprietary RDMBS functionality. This may include:

  • MySQL's encryption functions
  • PL/SQL constructs, pgplsql, or any other dialect's ROUTINE-language (maybe in the future)
 

4.2. The DSLContext API

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

DSLContext references a org.jooq.Configuration, an object that configures jOOQ's behaviour when executing queries (see SQL execution for more details). Unlike the static DSL, the DSLContext allow for creating SQL statements that are already "configured" and ready for execution.

Fluent creation of a DSLContext object

The DSLContext object can be created fluently from the DSL type:

// Create it from a pre-existing configuration
DSLContext create = DSL.using(configuration);

// Create it from ad-hoc arguments
DSLContext create = DSL.using(connection, dialect);

If you do not have a reference to a pre-existing Configuration object (e.g. created from org.jooq.impl.DefaultConfiguration), the various overloaded DSL.using() methods will create one for you.

Contents of a Configuration object

A Configuration can be supplied with these objects:

Usage of DSLContext

Wrapping a Configuration object, a DSLContext can construct statements, for later execution. An example is given here:

// The DSLContext is "configured" with a Connection and a SQLDialect
DSLContext create = DSL.using(connection, dialect);

// This select statement contains an internal reference to the DSLContext's Configuration:
Select<?> select = create.selectOne();

// Using the internally referenced Configuration, the select statement can now be executed:
Result<?> result = select.fetch();

Note that you do not need to keep a reference to a DSLContext. You may as well inline your local variable, and fluently execute a SQL statement as such:

// Execute a statement from a single execution chain:
Result<?> result =
DSL.using(connection, dialect)
   .select()
   .from(BOOK)
   .where(BOOK.TITLE.like("Animal%"))
   .fetch();
 

4.2.1. SQL Dialect

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

While jOOQ tries to represent the SQL standard as much as possible, many features are vendor-specific to a given database and to its "SQL dialect". jOOQ models this using the org.jooq.SQLDialect enum type.

The SQL dialect is one of the main attributes of a Configuration. Queries created from DSLContexts will assume dialect-specific behaviour when rendering SQL and binding bind values.

Some parts of the jOOQ API are officially supported only by a given subset of the supported SQL dialects. For instance, the Oracle CONNECT BY clause, which is supported by the Oracle and CUBRID databases, is annotated with a org.jooq.Support annotation, as such:

/**
 * Add an Oracle-specific <code>CONNECT BY</code> clause to the query
 */
@Support({ SQLDialect.CUBRID, SQLDialect.ORACLE })
SelectConnectByConditionStep<R> connectBy(Condition condition);

jOOQ API methods which are not annotated with the org.jooq.Support annotation, or which are annotated with the Support annotation, but without any SQL dialects can be safely used in all SQL dialects. An example for this is the SELECT statement factory method:

/**
 * Create a new DSL select statement.
 */
@Support
SelectSelectStep<R> select(Field<?>... fields);

jOOQ's SQL clause emulation capabilities

The aforementioned Support annotation does not only designate, which databases natively support a feature. It also indicates that a feature is emulated by jOOQ for some databases lacking this feature. An example of this is the DISTINCT predicate, a predicate syntax defined by SQL:1999 and implemented only by H2, HSQLDB, and Postgres:

A IS DISTINCT FROM B

Nevertheless, the IS DISTINCT FROM predicate is supported by jOOQ in all dialects, as its semantics can be expressed with an equivalent CASE expression. For more details, see the manual's section about the DISTINCT predicate.

jOOQ and the Oracle SQL dialect

Oracle SQL is much more expressive than many other SQL dialects. It features many unique keywords, clauses and functions that are out of scope for the SQL standard. Some examples for this are

jOOQ has a historic affinity to Oracle's SQL extensions. If something is supported in Oracle SQL, it has a high probability of making it into the jOOQ API

 

4.2.2. SQL Dialect Family

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In jOOQ 3.1, the notion of a SQLDialect.family() was introduced, in order to group several similar SQL dialects into a common family. An example for this is SQL Server, which is supported by jOOQ in various versions:

  • SQL Server: The "version-less" SQL Server version. This always maps to the latest supported version of SQL Server
  • SQL Server 2012: The SQL Server version 2012
  • SQL Server 2008: The SQL Server version 2008

In the above list, SQLSERVER is both a dialect and a family of three dialects. This distinction is used internally by jOOQ to distinguish whether to use the OFFSET .. FETCH clause (SQL Server 2012), or whether to emulate it using ROW_NUMBER() OVER() (SQL Server 2008).

 

4.2.3. Connection vs. DataSource

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Interact with JDBC Connections

While you can use jOOQ for SQL building only, you can also run queries against a JDBC java.sql.Connection. Internally, jOOQ creates java.sql.Statement or java.sql.PreparedStatement objects from such a Connection, in order to execute statements. The normal operation mode is to provide a Configuration with a JDBC Connection, whose lifecycle you will control yourself. This means that jOOQ will not actively close connections, rollback or commit transactions.

Note, in this case, jOOQ will internally use a org.jooq.impl.DefaultConnectionProvider, which you can reference directly if you prefer that. The DefaultConnectionProvider exposes various transaction-control methods, such as commit(), rollback(), etc.

Interact with JDBC DataSources

If you're in a Java EE or Spring context, however, you may wish to use a javax.sql.DataSource instead. Connections obtained from such a DataSource will be closed after query execution by jOOQ. The semantics of such a close operation should be the returning of the connection into a connection pool, not the actual closing of the underlying connection. Typically, this makes sense in an environment using distributed JTA transactions.

Note, in this case, jOOQ will internally use a org.jooq.impl.DataSourceConnectionProvider, which you can reference directly if you prefer that.

Inject custom behaviour

If your specific environment works differently from any of the above approaches, you can inject your own custom implementation of a ConnectionProvider into jOOQ. This is the API contract you have to fulfil:

public interface ConnectionProvider {

    // Provide jOOQ with a connection
    Connection acquire() throws DataAccessException;

    // Get a connection back from jOOQ
    void release(Connection connection) throws DataAccessException;
}
 

4.2.4. Custom data

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In advanced use cases of integrating your application with jOOQ, you may want to put custom data into your Configuration, which you can then access from your...

Here is an example of how to use the custom data API. Let's assume that you have written an ExecuteListener, that prevents INSERT statements, when a given flag is set to true:

public class NoInsertListener extends DefaultExecuteListener {

    @Override
    public void start(ExecuteContext ctx) {

        // This listener is active only, when your custom flag is set to true
        if (Boolean.TRUE.equals(ctx.configuration().data("com.example.my-namespace.no-inserts"))) {

            // If active, fail this execution, if an INSERT statement is being executed
            if (ctx.query() instanceof Insert) {
                throw new DataAccessException("No INSERT statements allowed");
            }
        }
    }
}

See the manual's section about ExecuteListeners to learn more about how to implement an ExecuteListener.

Now, the above listener can be added to your Configuration, but you will also need to pass the flag to the Configuration, in order for the listener to work:

// Create your Configuration
Configuration configuration = new DefaultConfiguration().set(connection).set(dialect);

// Set a new execute listener provider onto the configuration:
configuration.set(new DefaultExecuteListenerProvider(new NoInsertListener()));

// Use any String literal to identify your custom data
configuration.data("com.example.my-namespace.no-inserts", true);

// Try to execute an INSERT statement
try {
    DSL.using(configuration)
       .insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME)
       .values(1, "Orwell")
       .execute();

    // You shouldn't get here
    Assert.fail();
}

// Your NoInsertListener should be throwing this exception here:
catch (DataAccessException expected) {
    Assert.assertEquals("No INSERT statements allowed", expected.getMessage());
}

Using the data() methods, you can store and retrieve custom data in your Configurations.

 

4.2.5. Custom ExecuteListeners

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

ExecuteListeners are a useful tool to...

  • implement custom logging
  • apply triggers written in Java
  • collect query execution statistics

ExecuteListeners are hooked into your Configuration by returning them from an org.jooq.ExecuteListenerProvider:

// Create your Configuration
Configuration configuration = new DefaultConfiguration().set(connection).set(dialect);

// Hook your listener providers into the configuration:
configuration.set(
    new DefaultExecuteListenerProvider(new MyFirstListener()),
    new DefaultExecuteListenerProvider(new PerformanceLoggingListener()),
    new DefaultExecuteListenerProvider(new NoInsertListener())
);

See the manual's section about ExecuteListeners to see examples of such listener implementations.

 

4.2.6. Custom Settings

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The jOOQ Configuration allows for some optional configuration elements to be used by advanced users. The org.jooq.conf.Settings class is a JAXB-annotated type, that can be provided to a Configuration in several ways:

The most specific settings for a given context will apply.

If you wish to configure your settings through XML, but explicitly load them for a given Configuration, you can do so as well, using JAXB:

Settings settings = JAXB.unmarshal(new File("/path/to/settings.xml"), Settings.class);

Example

For example, if you want to indicate to jOOQ, that it should inline all bind variables, and execute static java.sql.Statement instead of binding its variables to java.sql.PreparedStatement, you can do so by creating the following DSLContext:

Settings settings = new Settings();
settings.setStatementType(StatementType.STATIC_STATEMENT);
DSLContext create = DSL.using(connection, dialect, settings);

More details

Please refer to the jOOQ runtime configuration XSD for more details:
https://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd

 

4.2.6.1. Auto-attach Records

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

By default, all records fetched through jOOQ are "attached" to the configuration that created them. This allows for features like updatable records as can be seen here:

AuthorRecord author =
DSL.using(configuration) // This configuration will be attached to any record produced by the below query.
   .selectFrom(AUTHOR)
   .where(AUTHOR.ID.eq(1))
   .fetchOne();

author.setLastName("Smith");
author.store(); // This store call operates on the "attached" configuration.

In some cases (e.g. when serialising records), it may be desirable not to attach the Configuration that created a record to the record. This can be achieved with the attachRecords setting:

Programmatic configuration

Settings settings = new Settings()
    .withAttachRecords(false); // Defaults to true

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <attachRecords>false</attachRecords>
</settings>
 

4.2.6.2. Backslash Escaping

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some databases (mainly MySQL and MariaDB) unfortunately chose to go an alternative, non-SQL-standard route when escaping string literals. Here's an example of how to escape a string containing apostrophes in different dialects:

SELECT 'I''m sure this is OK' AS val             -- Standard SQL escaping of apostrophe by doubling it.
SELECT 'I\'m certain this causes trouble' AS val -- Vendor-specific escaping of apostrophe by using a backslash.

As most databases don't support backslash escaping (and MySQL also allows for turning it off!), jOOQ by default also doesn't support it when inlining bind variables. However, this can lead to SQL injection vulnerabilities and syntax errors when not dealing with it carefully!

This feature is turned on by default and for historic reasons for MySQL and MariaDB.

  • DEFAULT (the - surprise! - default): Turns the feature ON for MySQL and MariaDB and OFF for all other dialects
  • ON: Turn the feature on.
  • OFF: Turn the feature off.

Example configuration

Settings settings = new Settings()
    .withBackslashEscaping(BackslashEscaping.OFF); // Default to DEFAULT
 

4.2.6.3. Execute Logging

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The executeLogging setting turns off the default logging implemented through org.jooq.tools.LoggerListener

Programmatic configuration

Settings settings = new Settings()
    .withExecuteLogging(false); // Defaults to true

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <executeLogging>false</executeLogging>
</settings>
 

4.2.6.4. Fetch Warnings

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Apart from JDBC exceptions, there is also the possibility to handle java.sql.SQLWarning, which are made available to jOOQ users through the java.sql.ExecuteListener SPI and the log

Users who do not wish to get these notifications (e.g. for performance reasons), may turn off fetching of warnings through the fetchWarnings setting:

Programmatic configuration

Settings settings = new Settings()
    .withFetchWarnings(false); // Defaults to true

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <fetchWarnings>false</fetchWarnings>
</settings>
 

4.2.6.5. Identifier style

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

By default, jOOQ will always generate quoted names for all identifiers (even if this manual omits this for readability). For instance:

SELECT "TABLE"."COLUMN" FROM "TABLE" -- SQL standard style
SELECT `TABLE`.`COLUMN` FROM `TABLE` -- MySQL style
SELECT [TABLE].[COLUMN] FROM [TABLE] -- SQL Server style

Quoting has the following effect on identifiers in most (but not all) databases:

  • It allows for using reserved names as object names, e.g. a table called "FROM" is usually possible only when quoted.
  • It allows for using special characters in object names, e.g. a column called "FIRST NAME" can be achieved only with quoting.
  • It turns what are mostly case-insensitive identifiers into case-sensitive ones, e.g. "name" and "NAME" are different identifiers, whereas name and NAME are not. Please consider your database manual to learn what the proper default case and default case sensitivity is.

The renderNameStyle setting allows for overriding the name of all identifiers in jOOQ to a consistent style. Possible options are:

  • QUOTED (the default): This will generate all names in their proper case with quotes around them.
  • AS_IS: This will generate all names in their proper case without quotes.
  • LOWER: This will transform all names to lower case.
  • UPPER: This will transform all names to upper case.

Programmatic configuration

Settings settings = new Settings()
    .withRenderNameStyle(RenderNameStyle.AS_IS); // Defaults to QUOTED

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <renderNameStyle>AS_IS</renderNameStyle>
</settings>
 

4.2.6.6. IN-list Padding

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Databases that feature a cursor cache / statement cache (e.g. Oracle, SQL Server, DB2, etc.) are highly optimised for prepared statement re-use. When a client sends a prepared statement to the server, the server will go to the cache and look up whether there already exists a previously calculated execution plan for the statement (i.e. the SQL string). This is called a "soft-parse" (in Oracle). If not, the execution plan is calculated on the fly. This is called a "hard-parse" (in Oracle).

Preventing hard-parses is extremely important in high throughput OLTP systems where queries are usually not very complex but are run millions of times in a short amount of time. Using bind variables, this is usually not a problem, with the exception of the IN predicate, which generates different SQL strings even when using bind variables:

-- All of these are different SQL statements:
SELECT * FROM AUTHOR WHERE ID IN (?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?)

This problem may not be obvious to Java / jOOQ developers, as they are always produced from the same jOOQ statement:

// All of these are the same jOOQ statement
DSL.using(configuration)
   .select()
   .from(AUTHOR)
   .where(AUTHOR.ID.in(collection))
   .fetch();

Depending on the possible sizes of the collection, it may be worth exploring using arrays or temporary tables as a workaround, or to reuse the original query that produced the set of IDs in the first place (through a semi-join). But sometimes, this is not possible. In this case, users can opt in to a third workaround: enabling the inListPadding setting. If enabled, jOOQ will "pad" the IN list to a length that is a power of two. So, the original queries would look like this instead:

-- Original
SELECT * FROM AUTHOR WHERE ID IN (?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?, ?)
-- Padded
SELECT * FROM AUTHOR WHERE ID IN (?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?, ?, ?, ?)
SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?, ?, ?, ?)

This technique will drastically reduce the number of possible SQL strings without impairing too much the usual cases where the IN list is small. When padding, the last bind variable will simply be repeated many times.

Usually, there is a better way - use this as a last resort!

Programmatic configuration

Settings settings = new Settings()
    .withInListPadding(true); // Default to false

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <inListPadding>true</inListPadding>
</settings>
 

4.2.6.7. JDBC Flags

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

JDBC statements feature a couple of flags that influence the execution of such a statement. Each of these flags can be configured through jOOQ's org.jooq.Query and org.jooq.ResultQuery on a statement-per-statement basis, but there's also the possibility to centrally specify a value for these flags. These are the three flags:

All of these flags are JDBC-only features with no direct effect on jOOQ. jOOQ only passes them through to the underlying statement.

Programmatic configuration

Settings settings = new Settings()
    .withQueryTimeout(5)
    .withMaxRows(1000)
    .withFetchSize(20);

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <queryTimeout>5</queryTimeout>
  <maxRows>1000</maxRows>
  <fetchSize>20</fetchSize>
</settings>
 

4.2.6.8. Keyword style

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In all SQL dialects, keywords are case insensitive, and this is also the default in jOOQ, which mostly generates lower-case keywords.

Users may wish to adapt this and they have these options for the renderKeywordStyle setting:

  • AS_IS (the default): Generate keywords as they are defined in the codebase (mostly lower case).
  • LOWER: Generate keywords in lower case.
  • UPPER: Generate keywords in upper case.

Programmatic configuration

Settings settings = new Settings()
    .withRenderKeywordStyle(RenderKeywordStyle.UPPER); // Defaults to AS_IS

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <renderKeywordStyle>UPPER</renderKeywordStyle>
</settings>
 

4.2.6.9. Map JPA Annotations

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The org.jooq.impl.DefaultRecordMapper supports basic JPA mapping (mostly @Table and @Column annotations). Looking up these annotations costs a slight extra overhead (mostly taken care of through reflection caching). It can be turned off using the mapJPAAnnotations setting:

Programmatic configuration

Settings settings = new Settings()
    .withMapJPAAnnotations(false); // Defaults to true

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <mapJPAAnnotations>false</mapJPAAnnotations>
</settings>
 

4.2.6.10. Object qualification

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

By default, jOOQ fully qualifies all objects with their catalog and schema names, if such qualification is made available by the code generator. For instance, the following SQL statement containing full qualification may be produced by jOOQ code with seemingly no qualification:

-- Full qualification on columns and tables
SELECT catalog.schema.table.column
FROM catalog.schema.table
DSL.using(configuration)
   .select(TABLE.COLUMN) // Column only qualified with table
   .from(TABLE)          // No qualification on table

While the jOOQ code is also implicitly fully qualified (see implied imports), it may not be desireable to use fully qualified object names in SQL. The renderCatalog and renderSchema settings are used for this.

Example configuration

new Settings()
  .withRenderCatalog(false)  // Defaults to true
  .withRenderSchema(false);  // Defaults to true

More sophisticated multitenancy approaches are available through the render mapping feature.

 

4.2.6.11. Optimistic Locking

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

There are two settings governing the behaviour of the jOOQ optimistic locking feature:

  • executeWithOptimisticLocking: This allows for turning off the feature entirely.
  • executeWithOptimisticLockingExcludeUnversioned: This allows for turning off the feature for updatable records who are not explicitly versioned.

Programmatic configuration

Settings settings = new Settings()
    .withExecuteWithOptimisticLocking(true)                     // Defaults to false
    .withExecuteWithOptimisticLockingExcludeUnversioned(false); // Defaults to false

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <executeWithOptimisticLocking>true</executeWithOptimisticLocking>
  <executeWithOptimisticLockingExcludeUnversioned>false</executeWithOptimisticLockingExcludeUnversioned>
</settings>

For more details, please refer to the manual's section about the optimistic locking feature.

 

4.2.6.12. Parameter types

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Bind values or bind parameters come in different flavours in different SQL databases. JDBC standardises on their syntax by allowing only ? (question mark) characters as placeholders for bind variables. Thus, jOOQ, by default, generates ? placeholders for JDBC consumptions.

Users who wish to use jOOQ with a different backend than JDBC can specify that all jOOQ bind values, including indexed parameters and named parameters generate alternative strings, other than ?. These are the current options:

  • INDEXED (the default): Generates indexed parameter placeholders using ?.
  • NAMED: Generates named parameter placeholders, such as :param for parameters that are named explicitly or :1 for unnamed, indexed parameters.
  • NAMED_OR_INLINED: Generates named parameter placeholders for parameters that are named explicitly and inlines all unnamed parameters.
  • INLINED: Inlines all parameters.

An example:

-- INDEXED
SELECT FIRST_NAME || ? FROM AUTHOR WHERE ID = ?
-- NAMED
SELECT FIRST_NAME || :1 FROM AUTHOR WHERE ID = :x
-- NAMED_OR_INLINED
SELECT FIRST_NAME || 'x' FROM AUTHOR WHERE ID = :x
-- INLINED
SELECT FIRST_NAME || 'x' FROM AUTHOR WHERE ID = 42
Param<String> x = val("x");
Param<Integer> i = param("x", 42);

DSL.using(configuration)
   .select(FIRST_NAME.concat(x))
   .from(AUTHOR)
   .where(ID.eq(i))
   .fetch();

Programmatic configuration

Settings settings = new Settings()
    .withParamType(ParamType.NAMED); // Defaults to INDEXED

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <paramType>NAMED</paramType>
</settings>

The following setting statementType may override this setting.

 

4.2.6.13. Reflection caching

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

All operations of the DefaultRecordMapper are cached in the Configuration by default for improved mapping and reflection speed. Users who prefer to override this cache, or work with their own custom record mapper provider may wish to turn off the out-of-the-box caching feature.

Programmatic configuration

Settings settings = new Settings()
    .withReflectionCaching(false); // Defaults to true

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <reflectionCaching>false</reflectionCaching>
</settings>
 

4.2.6.14. Return All Columns On Store

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

When using the updatable records feature, jOOQ always fetches the generated identity value, if such a value is available.

The identity value is not the only value that is generated by default. Specifically, there may be triggers that are used for auditing or other reasons, which generate LAST_UPDATE or LAST_UPDATE_BY values in a record. Users who wish to also automatically fetch these values after all store(), insert(), or update() calls may do so by specifying the returnAllOnUpdatableRecord setting. This setting depends on the availability of INSERT .. RETURNING, UPDATE .. RETURNING, and DELETE .. RETURNING statements, which are not available from all databases, in case of which a refresh() call may be issued, creating a separate round trip to the server.

Programmatic configuration

Settings settings = new Settings()
    .withReturnAllOnUpdatableRecord(true); // Defaults to false

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <returnAllOnUpdatableRecord>true</returnAllOnUpdatableRecord>
</settings>
 

4.2.6.15. Runtime schema and table mapping

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Mapping your DEV schema to a productive environment

You may wish to design your database in a way that you have several instances of your schema. This is useful when you want to cleanly separate data belonging to several customers / organisation units / branches / users and put each of those entities' data in a separate database or schema.

In our AUTHOR example this would mean that you provide a book reference database to several companies, such as My Book World and Books R Us. In that case, you'll probably have a schema setup like this:

  • DEV: Your development schema. This will be the schema that you base code generation upon, with jOOQ
  • MY_BOOK_WORLD: The schema instance for My Book World
  • BOOKS_R_US: The schema instance for Books R Us

Mapping DEV to MY_BOOK_WORLD with jOOQ

When a user from My Book World logs in, you want them to access the MY_BOOK_WORLD schema using classes generated from DEV. This can be achieved with the org.jooq.conf.RenderMapping class, that you can equip your Configuration's settings with. Take the following example:

Example configuration

Settings settings = new Settings()
    .withRenderMapping(new RenderMapping()
    .withSchemata(
        new MappedSchema().withInput("DEV")
                          .withOutput("MY_BOOK_WORLD"),
        new MappedSchema().withInput("LOG")
                          .withOutput("MY_BOOK_WORLD_LOG")));

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <renderMapping>
    <schemata>
      <schema>
        <input>DEV</input>
        <output>MY_BOOK_WORLD</output>
      </schema>
      <schema>
        <input>LOG</input>
        <output>MY_BOOK_WORLD_LOG</output>
      </schema>
    </schemata>
  </renderMapping>
</settings>

The query executed with a Configuration equipped with the above mapping will in fact produce this SQL statement:

SELECT *
FROM MY_BOOK_WORLD.AUTHOR
DSL.using(connection, dialect, settings)
   .selectFrom(DEV.AUTHOR)

This works because AUTHOR was generated from the DEV schema, which is mapped to the MY_BOOK_WORLD schema by the above settings.

Mapping of tables

Not only schemata can be mapped, but also tables. If you are not the owner of the database your application connects to, you might need to install your schema with some sort of prefix to every table. In our examples, this might mean that you will have to map DEV.AUTHOR to something MY_BOOK_WORLD.MY_APP__AUTHOR, where MY_APP__ is a prefix applied to all of your tables. This can be achieved by creating the following mapping:

Example configuration

Settings settings = new Settings()
    .withRenderMapping(new RenderMapping()
    .withSchemata(
        new MappedSchema().withInput("DEV")
                          .withTables(
         new MappedTable().withInput("AUTHOR")
                          .withOutput("MY_APP__AUTHOR"))));

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <renderMapping>
    <schemata>
      <schema>
        <input>DEV</input>
        <tables>
          <table>
            <input>AUTHOR</input>
            <output>MY_APP__AUTHOR</output>
          </table>
        </tables>
      </schema>
    </schemata>
  </renderMapping>
</settings>

The query executed with a Configuration equipped with the above mapping will in fact produce this SQL statement:

SELECT * FROM DEV.MY_APP__AUTHOR

Table mapping and schema mapping can be applied independently, by specifying several MappedSchema entries in the above configuration. jOOQ will process them in order of appearance and map at first match. Note that you can always omit a MappedSchema's output value, in case of which, only the table mapping is applied.

Using regular expressions

All of the above examples were using 1:1 constant name mappings where the input and output schema or table names are fixed by the configuration. With jOOQ 3.8, regular expression can be used as well for mapping, for example:

Example configuration

Settings settings = new Settings()
    .withRenderMapping(new RenderMapping()
    .withSchemata(
        new MappedSchema().withInputExpression(Pattern.compile("DEV_(.*)"))
                          .withOutput("PROD_$1")
                          .withTables(
         new MappedTable().withInputExpression(Pattern.compile("DEV_(.*)"))
                          .withOutput("PROD_$1"))));

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <renderMapping>
    <schemata>
      <schema>
        <inputExpression>DEV_(.*)</inputExpression>
        <output>PROD_$1</output>
        <tables>
          <table>
            <inputExpression>DEV_(.*)</inputExpression>
            <output>PROD_$1</output>
          </table>
        </tables>
      </schema>
    </schemata>
  </renderMapping>
</settings>

The only difference to the constant version is that the input field is replaced by the inputExpression field of type java.util.regex.Pattern, in case of which the meaning of the output field is a pattern replacement, not a constant replacement.

Hard-wiring mappings at code-generation time

Note that the manual's section about code generation schema mapping explains how you can hard-wire your catalog, schema and table mappings at code generation time.

Limitations

Mapped objects need to be known to the jOOQ org.jooq.RenderContext, which means that for example plain SQL templates and their contents cannot be mapped. See also features requiring code generation for more details.

 

4.2.6.16. Scalar subqueries for stored functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This setting is useful mostly for the Oracle database, which implements a feature called scalar subquery caching, which is a good tool to avoid the expensive PL/SQL-to-SQL context switch when predicates make use of stored function calls.

With this setting in place, all stored function calls embedded in SQL statements will be wrapped in a scalar subquery:

SELECT
  (SELECT my_package.format(LANGUAGE_ID) FROM dual)
FROM BOOK
DSL.using(configuration)
   .select(MyPackage.format(BOOK.LANGUAGE_ID))
   .from(BOOK)

If our table contains thousands of books, but only a dozen of LANGUAGE_ID values, then with scalar subquery caching, we can avoid most of the function calls and cache the result per LANGUAGE_ID.

Example configuration

Settings settings = new Settings()
    .withRenderScalarSubqueriesForStoredFunctions(true);
 

4.2.6.17. Statement Type

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

JDBC knows two types of statements:

The statementType setting allows for overriding the default of using prepared statements internally. There are two possible options for this setting:

  • PREPARED_STATEMENT (the default): Use prepared statements.
  • STATIC_STATEMENT: Use static statements. This enforces the paramType == INLINED. See parameter types

Programmatic configuration

Settings settings = new Settings()
    .withStatementType(StatementType.STATIC_STATEMENT); // Defaults to PREPARED_STATEMENT

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <statementType>STATIC_STATEMENT</statementType>
</settings>
 

4.2.6.18. Updatable Primary Keys

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In most database design guidelines, primary key values are expected to never change - an assumption that is essential to a normalised database.

As always, there are exceptions to these rules, and users may wish to allow for updatable primary key values in the updatable records feature (note: any value can always be updated through ordinary update statements). An example:

AuthorRecord author =
DSL.using(configuration) // This configuration will be attached to any record produced by the below query.
   .selectFrom(AUTHOR)
   .where(AUTHOR.ID.eq(1))
   .fetchOne();

author.setId(2);
author.store(); // The behaviour of this store call is governed by the updatablePrimaryKeys flag

The above store call depends on the value of the updatablePrimaryKeys flag:

  • false (the default): Since immutability of primary keys is assumed, the store call will create a new record (a copy) with the new primary key value.
  • true: Since mutablity of primary keys is allowed, the store call will change the primary key value from 1 to 2.

Programmatic configuration

Settings settings = new Settings()
    .withUpdatablePrimaryKeys(true); // Defaults to false

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.9.0.xsd">
  <updatablePrimaryKeys>true</updatablePrimaryKeys>
</settings>
 

4.2.7. Thread safety

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

org.jooq.Configuration, and by consequence org.jooq.DSLContext, make no thread safety guarantees, but by carefully observing a few rules, they can be shared in a thread safe way. We encourage sharing Configuration instances, because they contain caches for work not worth repeating, such as reflection field and method lookups for org.jooq.impl.DefaultRecordMapper. If you're using Spring or CDI for dependency injection, you will want to be able to inject a DSLContext instance everywhere you use it.

The following needs to be considered when attempting to share Configuration and DSLContext among threads:

  • Configuration is mutable for historic reasons. Calls to various Configuration.set() methods must be avoided after initialisation, should a Configuration (and by consequence DSLContext) instance be shared among threads. If you wish to modify some elements of a Configuration for single use, use the Configuration.derive() methods instead, which create a copy.
  • Configuration components, such as org.jooq.conf.Settings are mutable as well. The same rules for modification apply here.
  • Configuration allows for supplying user-defined SPI implementations (see above for examples). All of these must be thread safe as well, for their wrapping Configuration to be thread safe. If you are using a org.jooq.impl.DataSourceConnectionProvider, for instance, you must make sure that your javax.sql.DataSource is thread safe as well. This is usually the case when you use a third party connection pool.

As can be seen above, Configuration was designed to work in a thread safe way, despite it not making any such guarantee.

 

4.3. SQL Statements (DML)

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ currently supports 5 types of SQL statements. All of these statements are constructed from a DSLContext instance with an optional JDBC Connection or DataSource. If supplied with a Connection or DataSource, they can be executed. Depending on the query type, executed queries can return results.

 

4.3.1. jOOQ's DSL and model API

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ ships with its own DSL (or Domain Specific Language) that emulates SQL in Java. This means, that you can write SQL statements almost as if Java natively supported it, just like .NET's C# does with LINQ to SQL.

Here is an example to illustrate what that means:

-- Select all books by authors born after 1920,
-- named "Paulo" from a catalogue:
SELECT *
  FROM author a
  JOIN book b ON a.id = b.author_id
 WHERE a.year_of_birth > 1920
   AND a.first_name = 'Paulo'
 ORDER BY b.title
Result<Record> result =
create.select()
      .from(AUTHOR.as("a"))
      .join(BOOK.as("b")).on(a.ID.eq(b.AUTHOR_ID))
      .where(a.YEAR_OF_BIRTH.gt(1920)
      .and(a.FIRST_NAME.eq("Paulo")))
      .orderBy(b.TITLE)
      .fetch();

We'll see how the aliasing works later in the section about aliased tables

jOOQ as an internal domain specific language in Java (a.k.a. the DSL API)

Many other frameworks have similar APIs with similar feature sets. Yet, what makes jOOQ special is its informal BNF notation modelling a unified SQL dialect suitable for many vendor-specific dialects, and implementing that BNF notation as a hierarchy of interfaces in Java. This concept is extremely powerful, when using jOOQ with IDE syntax auto completion. Not only can you code much faster, your SQL code will be compile-checked to a certain extent. An example of a DSL query equivalent to the previous one is given here:

DSLContext create = DSL.using(connection, dialect);
Result<?> result = create.select()
                         .from(AUTHOR)
                         .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
                         .fetch();

Unlike other, simpler frameworks that use "fluent APIs" or "method chaining", jOOQ's BNF-based interface hierarchy will not allow bad query syntax. The following will not compile, for instance:

DSLContext create = DSL.using(connection, dialect);
Result<?> result = create.select()
                         .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
                      //  ^^^^ "join" is not possible here
                         .from(AUTHOR)
                         .fetch();

Result<?> result = create.select()
                         .from(AUTHOR)
                         .join(BOOK)
                         .fetch();
                      //  ^^^^^ "on" is missing here

Result<?> result = create.select(rowNumber())
                      //         ^^^^^^^^^ "over()" is missing here
                         .from(AUTHOR)
                         .fetch();

Result<?> result = create.select()
                         .from(AUTHOR)
                         .where(AUTHOR.ID.in(select(BOOK.TITLE).from(BOOK)))
                      //                     ^^^^^^^^^^^^^^^^^^
                      // AUTHOR.ID is of type Field<Integer> but subselect returns Record1<String>
                         .fetch();

Result<?> result = create.select()
                         .from(AUTHOR)
                         .where(AUTHOR.ID.in(select(BOOK.AUTHOR_ID, BOOK.ID).from(BOOK)))
                      //                     ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
                      // AUTHOR.ID is of degree 1 but subselect returns Record2<Integer, Integer>
                         .fetch();

History of SQL building and incremental query building (a.k.a. the model API)

Historically, jOOQ started out as an object-oriented SQL builder library like any other. This meant that all queries and their syntactic components were modeled as so-called QueryParts, which delegate SQL rendering and variable binding to child components. This part of the API will be referred to as the model API (or non-DSL API), which is still maintained and used internally by jOOQ for incremental query building. An example of incremental query building is given here:

DSLContext create = DSL.using(connection, dialect);
SelectQuery<Record> query = create.selectQuery();
query.addFrom(AUTHOR);

// Join books only under certain circumstances
if (join) {
    query.addJoin(BOOK, BOOK.AUTHOR_ID.eq(AUTHOR.ID));
}

Result<?> result = query.fetch();

This query is equivalent to the one shown before using the DSL syntax. In fact, internally, the DSL API constructs precisely this SelectQuery object. Note, that you can always access the SelectQuery object to switch between DSL and model APIs:

DSLContext create = DSL.using(connection, dialect);
SelectFinalStep<?> select = create.select().from(AUTHOR);

// Add the JOIN clause on the internal QueryObject representation
SelectQuery<?> query = select.getQuery();
query.addJoin(BOOK, BOOK.AUTHOR_ID.eq(AUTHOR.ID));

Mutability

Note, that for historic reasons, the DSL API mixes mutable and immutable behaviour with respect to the internal representation of the QueryPart being constructed. While creating conditional expressions, column expressions (such as functions) assumes immutable behaviour, creating SQL statements does not. In other words, the following can be said:

// Conditional expressions (immutable)
// -----------------------------------
Condition a = BOOK.TITLE.eq("1984");
Condition b = BOOK.TITLE.eq("Animal Farm");

// The following can be said
a       != a.or(b); // or() does not modify a
a.or(b) != a.or(b); // or() always creates new objects

// Statements (mutable)
// --------------------
SelectFromStep<?> s1 = select();
SelectJoinStep<?> s2 = s1.from(BOOK);
SelectJoinStep<?> s3 = s1.from(AUTHOR);

// The following can be said
s1 == s2; // The internal object is always the same
s2 == s3; // The internal object is always the same

On the other hand, beware that you can always extract and modify bind values from any QueryPart.

 

4.3.2. The WITH clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL:1999 standard specifies the WITH clause to be an optional clause for the SELECT statement, in order to specify common table expressions (also: CTE). Many other databases (such as PostgreSQL, SQL Server) also allow for using common table expressions also in other DML clauses, such as the INSERT statement, UPDATE statement, DELETE statement, or MERGE statement.

When using common table expressions with jOOQ, there are essentially two approaches:

  • Declaring and assigning common table expressions explicitly to names
  • Inlining common table expressions into a SELECT statement

Explicit common table expressions

The following example makes use of names to construct common table expressions, which can then be supplied to a WITH clause or a FROM clause of a SELECT statement:

-- Pseudo-SQL for a common table expression specification
"t1" ("f1", "f2") AS (SELECT 1, 'a')
// Code for creating a CommonTableExpression instance
name("t1").fields("f1", "f2").as(select(val(1), val("a")));

The above expression can be assigned to a variable in Java and then be used to create a full SELECT statement:







WITH "t1" ("f1", "f2") AS (SELECT 1, 'a'),
     "t2" ("f3", "f4") AS (SELECT 2, 'b')
SELECT
    "t1"."f1" + "t2"."f3" AS "add",
    "t1"."f2" || "t2"."f4" AS "concat"
FROM "t1", "t2"
;
CommonTableExpression<Record2<Integer, String>> t1 =
  name("t1").fields("f1", "f2").as(select(val(1), val("a")));
CommonTableExpression<Record2<Integer, String>> t2 =
  name("t2").fields("f3", "f4").as(select(val(2), val("b")));

Result<?> result2 =
create.with(t1)
      .with(t2)
      .select(
          t1.field("f1").add(t2.field("f3")).as("add"),
          t1.field("f2").concat(t2.field("f4")).as("concat"))
      .from(t1, t2)
      .fetch();

Note that the org.jooq.CommonTableExpression type extends the commonly used org.jooq.Table type, and can thus be used wherever a table can be used.

Inlined common table expressions

If you're just operating on plain SQL, you may not need to keep intermediate references to such common table expressions. An example of such usage would be this:

WITH "a" AS (SELECT
               1 AS "x",
               'a' AS "y"
            )
SELECT
FROM "a"
;
create.with("a").as(select(
                        val(1).as("x"),
                        val("a").as("y")
                   ))
      .select()
      .from(table(name("a")))
      .fetch();
 

4.3.3. The WITH RECURSIVE clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The various SQL dialects do not agree on the use of RECURSIVE when writing recursive common table expressions. When using jOOQ, always use the DSLContext.withRecursive() or DSL.withRecursive() methods, and jOOQ will render the RECURSIVE keyword, if needed.

Assuming a table like this:

CREATE TABLE directory (
  id           INT NOT NULL,
  parent_id    INT,

  -- In PostgreSQL, use TEXT instead, to work around https://github.com/jOOQ/jOOQ/issues/12067
  label        VARCHAR(50),

  CONSTRAINT pk_directory PRIMARY KEY (id),
  CONSTRAINT fk_directory FOREIGN KEY (parent_id) REFERENCES directory (id)
);

INSERT INTO directory VALUES ( 1, null, 'C:');
INSERT INTO directory VALUES ( 2,    1, 'eclipse');
INSERT INTO directory VALUES ( 3,    2, 'configuration');
INSERT INTO directory VALUES ( 4,    2, 'dropins');
INSERT INTO directory VALUES ( 5,    2, 'features');
INSERT INTO directory VALUES ( 7,    2, 'plugins');
INSERT INTO directory VALUES ( 8,    2, 'readme');
INSERT INTO directory VALUES ( 9,    8, 'readme_eclipse.html');
INSERT INTO directory VALUES (10,    2, 'src');
INSERT INTO directory VALUES (11,    2, 'eclipse.exe');

Using WITH RECURSIVE, you can now query the structure of this directory as follows:

WITH RECURSIVE t (
  id,
  name,
  path
) AS (
  SELECT
    DIRECTORY.ID,
    DIRECTORY.LABEL,
    DIRECTORY.LABEL
  FROM
    DIRECTORY
  WHERE
    DIRECTORY.PARENT_ID IS NULL
  UNION ALL
  SELECT
    DIRECTORY.ID,
    DIRECTORY.LABEL,
    t.path
      || '\'
      || DIRECTORY.LABEL
  FROM
    t
  JOIN
    DIRECTORY
  ON t.id = DIRECTORY.PARENT_ID
)
SELECT *
FROM
  t;
CommonTableExpression<?> cte = name("t").fields(
  "id",
  "name",
  "path"
).as(
  select(
    DIRECTORY.ID,
    DIRECTORY.LABEL,
    DIRECTORY.LABEL)
  .from(DIRECTORY)
  .where(DIRECTORY.PARENT_ID.isNull())
  .unionAll(
  select(
    DIRECTORY.ID,
    DIRECTORY.LABEL,
    field(name("t", "path"), VARCHAR)
      .concat("\\")
      .concat(DIRECTORY.LABEL))
  .from(table(name("t")))
  .join(DIRECTORY)
  .on(field(name("t", "id"), INTEGER)
    .eq(DIRECTORY.PARENT_ID)))
);

System.out.println(
    create.withRecursive(cte)
          .selectFrom(cte)
          .fetch()
);

The output would look like this:

+----+---------------------+---------------------------------------+
| id | name                | path                                  |
+----+---------------------+---------------------------------------+
| 1  | C:                  | C:                                    |
| 2  | eclipse             | C:\eclipse                            |
| 3  | configuration       | C:\eclipse\configuration              |
| 4  | dropins             | C:\eclipse\dropins                    |
| 11 | eclipse.exe         | C:\eclipse\eclipse.exe                |
| 5  | features            | C:\eclipse\features                   |
| 7  | plugins             | C:\eclipse\plugins                    |
| 8  | readme              | C:\eclipse\readme                     |
| 9  | readme_eclipse.html | C:\eclipse\readme\readme_eclipse.html |
| 10 | src                 | C:\eclipse\src                        |
+----+---------------------+---------------------------------------+

Caveats

The SQL language expresses the recursion syntactically, meaning the table t in the above example is being referenced from within the declaration of t. This isn't possible in a language like Java. Hence, we must use the identifier API to construct identifier references for tables and columns. This technique usually appears a bit more verbose than ordinary jOOQ API usage that is based on generated code for your schema.

 

4.3.4. The SELECT statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

When you don't just perform CRUD (i.e. SELECT * FROM your_table WHERE ID = ?), you're usually generating new record types using custom projections. With jOOQ, this is as intuitive, as if using SQL directly. A more or less complete example of the "standard" SQL syntax, plus some extensions, is provided by a query like this:

SELECT from a complex table expression

-- get all authors' first and last names, and the number
-- of books they've written in German, if they have written
-- more than five books in German in the last three years
-- (from 2011), and sort those authors by last names
-- limiting results to the second and third row, locking
-- the rows for a subsequent update... whew!

  SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, COUNT(*)
    FROM AUTHOR
    JOIN BOOK ON AUTHOR.ID = BOOK.AUTHOR_ID
   WHERE BOOK.LANGUAGE = 'DE'
     AND BOOK.PUBLISHED > '2008-01-01'
GROUP BY AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME
  HAVING COUNT(*) > 5
ORDER BY AUTHOR.LAST_NAME ASC NULLS FIRST
   LIMIT 2
  OFFSET 1
     FOR UPDATE
// And with jOOQ...



DSLContext create = DSL.using(connection, dialect);

create.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, count())
      .from(AUTHOR)
      .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .where(BOOK.LANGUAGE.eq("DE"))
      .and(BOOK.PUBLISHED.gt("2008-01-01"))
      .groupBy(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .having(count().gt(5))
      .orderBy(AUTHOR.LAST_NAME.asc().nullsFirst())
      .limit(2)
      .offset(1)
      .forUpdate()
      .fetch();

Details about the various clauses of this query will be provided in subsequent sections.

SELECT from single tables

A very similar, but limited API is available, if you want to select from single tables in order to retrieve TableRecords or even UpdatableRecords. The decision, which type of select to create is already made at the very first step, when you create the SELECT statement with the DSL or DSLContext types:

public <R extends Record> SelectWhereStep<R> selectFrom(Table<R> table);

As you can see, there is no way to further restrict/project the selected fields. This just selects all known TableFields in the supplied Table, and it also binds <R extends Record> to your Table's associated Record. An example of such a Query would then be:

BookRecord book = create.selectFrom(BOOK)
                        .where(BOOK.LANGUAGE.eq("DE"))
                        .orderBy(BOOK.TITLE)
                        .fetchAny();

The "reduced" SELECT API is limited in the way that it skips DSL access to any of these clauses:

In most parts of this manual, it is assumed that you do not use the "reduced" SELECT API. For more information about the simple SELECT API, see the manual's section about fetching strongly or weakly typed records.

 

4.3.4.1. SELECT clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SELECT clause lets you project your own record types, referencing table fields, functions, arithmetic expressions, etc. The DSL type provides several methods for expressing a SELECT clause:

-- The SELECT clause
SELECT BOOK.ID, BOOK.TITLE
SELECT BOOK.ID, TRIM(BOOK.TITLE)
// Provide a varargs Fields list to the SELECT clause:
Select<?> s1 = create.select(BOOK.ID, BOOK.TITLE);
Select<?> s2 = create.select(BOOK.ID, trim(BOOK.TITLE));

The following sections illustrate various features and subclauses of the SELECT clause.

 

4.3.4.1.1. Projection type safety

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Since jOOQ 3.0, records and row value expressions up to degree 22 are now generically typesafe. This is reflected by an overloaded SELECT (and SELECT DISTINCT) API in both DSL and DSLContext. An extract from the DSL type:

// Non-typesafe select methods:
public static SelectSelectStep<Record> select(Collection<? extends SelectField<?>> fields);
public static SelectSelectStep<Record> select(SelectField<?>... fields);

// Typesafe select methods:
public static <T1>         SelectSelectStep<Record1<T1>>         select(SelectField<T1> field1);
public static <T1, T2>     SelectSelectStep<Record2<T1, T2>>     select(SelectField<T1> field1, SelectField<T2> field2);
// [...]

The type that is being projected is the org.jooq.SelectField, see also the next section about SelectField. Since the generic R type is bound to some Record[N], the associated T type information can be used in various other contexts, e.g. the IN predicate. Such a SELECT statement can be assigned typesafely:

Select<Record2<Integer, String>> s1 = create.select(BOOK.ID, BOOK.TITLE);
Select<Record2<Integer, String>> s2 = create.select(BOOK.ID, trim(BOOK.TITLE));

// Alternatively, just use var to infer the type:
var s3 = create.select(BOOK.ID, trim(BOOK.TITLE));

For more information about typesafe record types with degree up to 22, see the manual's section about Record1 to Record22.

 

4.3.4.1.2. SelectField

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The org.jooq.SelectField type is used by any projection of the SELECT clause and the INSERT .. RETURNING clause. It has numerous subtypes, which are allowed as projections in jOOQ:

  • More subtypes are available from future jOOQ versions.
 

4.3.4.1.3. SELECT DISTINCT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DISTINCT keyword can be included in the method name, when constructing a SELECT clause, to remove duplicate tuples from the projection.

SELECT DISTINCT BOOK.TITLE FROM BOOK
create.selectDistinct(BOOK.TITLE).from(BOOK).fetch();

Dialect support

This example using jOOQ:

selectDistinct(BOOK.TITLE).from(BOOK)

Translates to the following dialect specific expressions:

-- All dialects
SELECT DISTINCT BOOK.TITLE
FROM BOOK
 

4.3.4.1.4. Convenience methods

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some commonly used projections can be easily created using convenience methods:

-- Simple SELECTs
SELECT COUNT(*)
SELECT 0 -- Not a bind variable
SELECT 1 -- Not a bind variable
// Select commonly used values
Result<?> result1 = create.selectCount().fetch();
Result<?> result2 = create.selectZero().fetch();
Result<?> result3 = create.selectOne().fetch();

Which are short forms for creating Column expressions from the org.jooq.impl.DSL API

-- Simple SELECTs
SELECT COUNT(*)
SELECT 0 -- Not a bind variable
SELECT ? -- A bind variable
// Select commonly used values
Result<?> result1 = create.select(count()).fetch();
Result<?> result2 = create.select(inline(0)).fetch();
Result<?> result3 = create.select(val(1)).fetch();
 

4.3.4.2. FROM clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL FROM clause allows for specifying any number of table expressions to select data from. The following are examples of how to form normal FROM clauses:

SELECT 1 FROM BOOK
SELECT 1 FROM BOOK, AUTHOR
SELECT 1 FROM BOOK "b", AUTHOR "a"
create.selectOne().from(BOOK).fetch();
create.selectOne().from(BOOK, AUTHOR).fetch();
create.selectOne().from(BOOK.as("b"), AUTHOR.as("a")).fetch();

Read more about aliasing in the manual's section about aliased tables.

More advanced table expressions

Apart from simple tables, you can pass any arbitrary table expression to the jOOQ FROM clause. This may include unnested cursors in Oracle:

SELECT *
FROM TABLE(
    DBMS_XPLAN.DISPLAY_CURSOR(null, null, 'ALLSTATS')
);
create.select()
      .from(table(
          DbmsXplan.displayCursor(null, null, "ALLSTATS")
      ).fetch();

Note, in order to access the DbmsXplan package, you can use the code generator to generate Oracle's SYS schema.

Selecting FROM DUAL with jOOQ

In many SQL dialects, FROM is a mandatory clause, in some it isn't. jOOQ allows you to omit the FROM clause, returning just one record. An example:

SELECT 1 FROM DUAL
SELECT 1
DSL.using(SQLDialect.ORACLE).selectOne().fetch();
DSL.using(SQLDialect.POSTGRES).selectOne().fetch();

Read more about dual or dummy tables in the manual's section about the DUAL table. The following are examples of how to form normal FROM clauses:

 

4.3.4.3. JOIN operator

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ supports many different types of standard and non-standard SQL JOIN operations. All of these JOIN methods can be called on org.jooq.Table types the (more info in joined tables section), or directly after the FROM clause for convenience. The following example joins AUTHOR and BOOK

DSLContext create = DSL.using(connection, dialect);

// Call "join" directly on the AUTHOR table
Result<?> result = create.select()
                         .from(AUTHOR.join(BOOK)
                                     .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
                         .fetch();

// Call "join" on the type returned by "from"
Result<?> result = create.select()
                         .from(AUTHOR)
                         .join(BOOK)
                         .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
                         .fetch();

The two syntaxes will produce the same SQL statement. However, calling "join" on org.jooq.Table objects allows for more powerful, nested JOIN expressions (if you can handle the parentheses):

SELECT *
FROM AUTHOR
LEFT OUTER JOIN (
  BOOK JOIN BOOK_TO_BOOK_STORE
       ON BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
)
ON BOOK.AUTHOR_ID = AUTHOR.ID
 
// Nest joins and provide JOIN conditions only at the end
create.select()
      .from(AUTHOR
      .leftOuterJoin(BOOK
        .join(BOOK_TO_BOOK_STORE)
        .on(BOOK_TO_BOOK_STORE.BOOK_ID.eq(BOOK.ID)))
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
      .fetch();

For more information about the different types of join, please refer to the joined tables section.

 

4.3.4.4. WHERE clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The WHERE clause can be used for JOIN or filter predicates, in order to restrict the data returned by the table expressions supplied to the previously specified from clause and join clause. Here is an example:

SELECT *
FROM BOOK
WHERE AUTHOR_ID = 1
AND TITLE = '1984'
 
create.select()
      .from(BOOK)
      .where(BOOK.AUTHOR_ID.eq(1))
      .and(BOOK.TITLE.eq("1984"))
      .fetch();

The above syntax is convenience provided by jOOQ, allowing you to connect the org.jooq.Condition supplied in the WHERE clause with another condition using an AND operator. You can of course also create a more complex condition and supply that to the WHERE clause directly (observe the different placing of parentheses). The results will be the same:

SELECT *
FROM BOOK
WHERE AUTHOR_ID = 1
AND TITLE = '1984'
 
create.select()
      .from(BOOK)
      .where(BOOK.AUTHOR_ID.eq(1).and(
             BOOK.TITLE.eq("1984")))
      .fetch();

You will find more information about creating conditional expressions later in the manual.

 

4.3.4.5. CONNECT BY clause

Applies to ❌ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The Oracle database knows a very succinct syntax for creating hierarchical queries: the CONNECT BY clause, which is fully supported by jOOQ, including all related functions and pseudo-columns. A more or less formal definition of this clause is given here:

--   SELECT ..
--     FROM ..
--    WHERE ..
 CONNECT BY [ NOCYCLE ] condition [ AND condition, ... ] [ START WITH condition ]
-- GROUP BY ..
-- ORDER [ SIBLINGS ] BY ..

An example for an iterative query, iterating through values between 1 and 5 is this:

SELECT LEVEL
FROM DUAL
CONNECT BY LEVEL <= 5
 
// Get a table with elements 1, 2, 3, 4, 5
create.select(level())
      .connectBy(level().le(5))
      .fetch();

Here's a more complex example where you can recursively fetch directories in your database, and concatenate them to a path:

SELECT
  SUBSTR(SYS_CONNECT_BY_PATH(DIRECTORY.NAME, '/'), 2)
FROM DIRECTORY
CONNECT BY
  PRIOR DIRECTORY.ID = DIRECTORY.PARENT_ID
START WITH DIRECTORY.PARENT_ID IS NULL
ORDER BY 1
 
.select(
   substring(sysConnectByPath(DIRECTORY.NAME, "/"), 2))
.from(DIRECTORY)
.connectBy(
   prior(DIRECTORY.ID).eq(DIRECTORY.PARENT_ID))
.startWith(DIRECTORY.PARENT_ID.isNull())
.orderBy(1)
.fetch();

The output might then look like this

+------------------------------------------------+
|substring                                       |
+------------------------------------------------+
|C:                                              |
|C:/eclipse                                      |
|C:/eclipse/configuration                        |
|C:/eclipse/dropins                              |
|C:/eclipse/eclipse.exe                          |
+------------------------------------------------+
|...21 record(s) truncated...

Some of the supported functions and pseudo-columns are these (available from the DSL):

  • LEVEL
  • CONNECT_BY_IS_CYCLE
  • CONNECT_BY_IS_LEAF
  • CONNECT_BY_ROOT
  • SYS_CONNECT_BY_PATH
  • PRIOR

If this syntax is unavailable in your dialect, starting from jOOQ 3.15, it is emulated in parts using WITH RECURSIVE.

ORDER SIBLINGS

The Oracle database allows for specifying a SIBLINGS keyword in the ORDER BY clause. Instead of ordering the overall result, this will only order siblings among each other, keeping the hierarchy intact. An example is given here:

SELECT DIRECTORY.NAME
FROM DIRECTORY
CONNECT BY
  PRIOR DIRECTORY.ID = DIRECTORY.PARENT_ID
START WITH DIRECTORY.PARENT_ID IS NULL
ORDER SIBLINGS BY 1
 
.select(DIRECTORY.NAME)
.from(DIRECTORY)
.connectBy(
   prior(DIRECTORY.ID).eq(DIRECTORY.PARENT_ID))
.startWith(DIRECTORY.PARENT_ID.isNull())
.orderSiblingsBy(1)
.fetch();
 

4.3.4.6. GROUP BY clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

GROUP BY can be used to create unique groups of data, to form aggregations, to remove duplicates and for other reasons. It will transform your previously defined set of table expressions, and return only one record per unique group as specified in this clause.

 

4.3.4.6.1. GROUP BY columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The GROUP BY columns list specifies the columns whose values are used to form groups. The group columns can then be projected, whereas all the non-group columns can be aggregated. An example of such a grouped aggregation is this query:

SELECT AUTHOR_ID, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID
 
create.select(BOOK.AUTHOR_ID, count())
      .from(BOOK)
      .groupBy(BOOK.AUTHOR_ID)
      .fetch();

The above example counts all books per author.

Note: a different and more powerful way of grouping data is to use the WINDOW clause and window functions.

Dialect support

This example using jOOQ:

select(BOOK.AUTHOR_ID, count()).from(BOOK).groupBy(BOOK.AUTHOR_ID)

Translates to the following dialect specific expressions:

-- All dialects
SELECT
  BOOK.AUTHOR_ID,
  count(*)
FROM BOOK
GROUP BY BOOK.AUTHOR_ID
 

4.3.4.6.2. GROUP BY ROLLUP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. ROLLUP is one way to do this.

SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY ROLLUP (AUTHOR_ID, LANGUAGE_ID)
 
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count())
      .from(BOOK)
      .groupBy(rollup(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
      .fetch();

The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:

SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID, LANGUAGE_ID
UNION ALL
SELECT AUTHOR_ID, NULL, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID
UNION ALL
SELECT NULL, NULL, COUNT(*)
FROM BOOK
GROUP BY ()

The ROLLUP function is just syntax sugar for a more complex GROUPING SETS specification. In general:

-- This
ROLLUP (A, B, C)

-- Is just short for this
GROUPING SETS ((A, B, C), (A, B), (A), ())

Dialect support

This example using jOOQ:

select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(rollup(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, MARIADB, MYSQL
SELECT
  BOOK.AUTHOR_ID,
  BOOK.LANGUAGE_ID,
  count(*)
FROM BOOK
GROUP BY BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID
WITH ROLLUP

-- AURORA_POSTGRES, DB2, DUCKDB, HANA, MEMSQL, ORACLE, POSTGRES, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA
SELECT
  BOOK.AUTHOR_ID,
  BOOK.LANGUAGE_ID,
  count(*)
FROM BOOK
GROUP BY ROLLUP (BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID)

-- ACCESS, ASE, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, REDSHIFT, SQLITE, YUGABYTEDB
/* UNSUPPORTED */
 

4.3.4.6.3. GROUP BY CUBE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. CUBE is one way to do this.

SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY CUBE (AUTHOR_ID, LANGUAGE_ID)
 
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count())
      .from(BOOK)
      .groupBy(cube(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
      .fetch();

The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:

SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID, LANGUAGE_ID
UNION ALL
SELECT AUTHOR_ID, NULL, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID
SELECT NULL, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY LANGUAGE_ID
UNION ALL
SELECT NULL, NULL, COUNT(*)
FROM BOOK
GROUP BY ()

The CUBE function is just syntax sugar for a more complex GROUPING SETS specification. In general:

-- This
CUBE (A, B, C)

-- Is just short for this
GROUPING SETS ((A, B, C), (A, B), (A, C), (B, C), (A), (B), (C), ())

Dialect support

This example using jOOQ:

select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(cube(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DB2, DUCKDB, HANA, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA
SELECT
  BOOK.AUTHOR_ID,
  BOOK.LANGUAGE_ID,
  count(*)
FROM BOOK
GROUP BY CUBE (BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, YUGABYTEDB
/* UNSUPPORTED */
 

4.3.4.6.4. GROUP BY GROUPING SETS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. GROUPING SETS is one way to do this.

SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY GROUPING SETS ((AUTHOR_ID), (LANGUAGE_ID))
 
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count())
      .from(BOOK)
      .groupBy(groupingSets(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
      .fetch();

The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:

SELECT AUTHOR_ID, NULL AS LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID
UNION ALL
SELECT NULL, LANGUAGE_ID, COUNT(*)
FROM BOOK
GROUP BY LANGUAGE_ID

Note that the most common GROUPING SETS specifications have a dedicated, special syntax:

Dialect support

This example using jOOQ:

select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(groupingSets(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DB2, DUCKDB, HANA, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA
SELECT
  BOOK.AUTHOR_ID,
  BOOK.LANGUAGE_ID,
  count(*)
FROM BOOK
GROUP BY GROUPING SETS (
  (BOOK.AUTHOR_ID),
  (BOOK.LANGUAGE_ID)
)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, YUGABYTEDB
/* UNSUPPORTED */
 

4.3.4.6.5. GROUP BY empty grouping set

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A special kind of GROUPING SET is the empty grouping set, which can be achieved in standard SQL and many SQL dialects using GROUP BY (). It is implicit, whenever an aggregate function is present in a query, but not an explicit GROUP BY clause.

SELECT COUNT(*)
FROM BOOK
GROUP BY ()
 
create.selectCount()
      .from(BOOK)
      .groupBy()
      .fetch();

Dialect support

This example using jOOQ:

selectCount().from(BOOK).groupBy()

Translates to the following dialect specific expressions:

-- ACCESS
SELECT count(*)
FROM BOOK, (select count(*) dual from MSysResources) as empty_grouping_dummy_table
GROUP BY empty_grouping_dummy_table.dual

-- ASE, BIGQUERY, SQLDATAWAREHOUSE
SELECT count(*)
FROM BOOK, (select 1 as dual) as empty_grouping_dummy_table
GROUP BY empty_grouping_dummy_table.dual

-- AURORA_MYSQL, MEMSQL
SELECT count(*)
FROM BOOK
GROUP BY (SELECT 1
FROM DUAL)

-- AURORA_POSTGRES, DB2, DUCKDB, EXASOL, H2, ORACLE, POSTGRES, SQLSERVER, SYBASE, TERADATA, TRINO
SELECT count(*)
FROM BOOK
GROUP BY ()

-- COCKROACHDB, MARIADB, MYSQL, REDSHIFT, SQLITE, VERTICA, YUGABYTEDB
SELECT count(*)
FROM BOOK
GROUP BY (SELECT 1)

-- DERBY, HSQLDB
SELECT count(*)
FROM BOOK
GROUP BY 0

-- FIREBIRD
SELECT count(*)
FROM BOOK
GROUP BY (SELECT 1
FROM RDB$DATABASE)

-- HANA, SNOWFLAKE
SELECT count(*)
FROM BOOK
GROUP BY GROUPING SETS (())

-- INFORMIX
SELECT count(*)
FROM BOOK, (select 1 as dual from systables where tabid = 1) as empty_grouping_dummy_table
GROUP BY empty_grouping_dummy_table.dual
 

4.3.4.7. HAVING clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The HAVING clause is commonly used to further restrict data resulting from a previously issued GROUP BY clause. An example, selecting only those authors that have written at least two books:

SELECT AUTHOR_ID, COUNT(*)
FROM BOOK
GROUP BY AUTHOR_ID
HAVING COUNT(*) >= 2
 
create.select(BOOK.AUTHOR_ID, count())
      .from(BOOK)
      .groupBy(AUTHOR_ID)
      .having(count().ge(2))
      .fetch();

According to the SQL standard, you may omit the GROUP BY clause and still issue a HAVING clause. This will implicitly GROUP BY (). jOOQ also supports this syntax. The following example selects one record, only if there are at least 4 books in the books table:

SELECT COUNT(*)
FROM BOOK
HAVING COUNT(*) >= 4
 
create.select(count(*))
      .from(BOOK)
      .having(count().ge(4))
      .fetch();
 

4.3.4.8. WINDOW clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL:2003 standard supports a WINDOW clause that allows for specifying WINDOW frames for reuse in SELECT clauses and ORDER BY clauses.




SELECT
  LAG(first_name, 1) OVER w "prev",
  first_name,
  LEAD(first_name, 1) OVER w "next"
FROM author
WINDOW w AS (ORDER first_name)
ORDER BY first_name DESC
 
WindowDefinition w = name("w").as(
  orderBy(PEOPLE.FIRST_NAME));

create.select(
         lag(AUTHOR.FIRST_NAME, 1).over(w).as("prev"),
         AUTHOR.FIRST_NAME,
         lead(AUTHOR.FIRST_NAME, 1).over(w).as("next"))
      .from(AUTHOR)
      .window(w)
      .orderBy(AUTHOR.FIRST_NAME.desc())
      .fetch();

Note that in order to create such a window definition, we need to first create a name reference using DSL.name().

Even if only PostgreSQL and Sybase SQL Anywhere natively support this great feature, jOOQ can emulate it by expanding any org.jooq.WindowDefinition and org.jooq.WindowSpecification types that you pass to the window() method - if the database supports window functions at all.

Some more information about window functions and the WINDOW clause can be found on our blog: https://blog.jooq.org/probably-the-coolest-sql-feature-window-functions/

 

4.3.4.9. ORDER BY clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Databases are allowed to return data in any arbitrary order, unless you explicitly declare that order in the ORDER BY clause. In jOOQ, this is straight-forward:

SELECT AUTHOR_ID, TITLE
FROM BOOK
ORDER BY AUTHOR_ID ASC, TITLE DESC
 
create.select(BOOK.AUTHOR_ID, BOOK.TITLE)
      .from(BOOK)
      .orderBy(BOOK.AUTHOR_ID.asc(), BOOK.TITLE.desc())
      .fetch();

Any jOOQ column expression (or field) can be transformed into an org.jooq.SortField by calling the asc() and desc() methods.

Ordering by field index

The SQL standard allows for specifying integer literals (literals, not bind values!) to reference column indexes from the projection (SELECT clause). This may be useful if you do not want to repeat a lengthy expression, by which you want to order - although most databases also allow for referencing aliased column references in the ORDER BY clause. An example of this is given here:

SELECT AUTHOR_ID, TITLE
FROM BOOK
ORDER BY 1 ASC, 2 DESC
 
create.select(BOOK.AUTHOR_ID, BOOK.TITLE)
      .from(BOOK)
      .orderBy(one().asc(), inline(2).desc())
      .fetch();

Note, how one() is used as a convenience short-cut for inline(1)

Ordering and NULLS

A few databases support the SQL standard "null ordering" clause in sort specification lists, to define whether NULL values should come first or last in an ordered result.

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME
FROM AUTHOR
ORDER BY LAST_NAME ASC,
         FIRST_NAME ASC NULLS LAST
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .orderBy(AUTHOR.LAST_NAME.asc(),
               AUTHOR.FIRST_NAME.asc().nullsLast())
      .fetch();

If your database doesn't support this syntax, jOOQ emulates it using a CASE expression as follows

SELECT
  AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME
FROM AUTHOR
ORDER BY LAST_NAME ASC,
         CASE WHEN FIRST_NAME IS NULL
              THEN 1 ELSE 0 END ASC,
         FIRST_NAME ASC

Ordering using CASE expressions

Using CASE expressions in SQL ORDER BY clauses is a common pattern, if you want to introduce some sort indirection / sort mapping into your queries. As with SQL, you can add any type of column expression into your ORDER BY clause. For instance, if you have two favourite books that you always want to appear on top, you could write:

SELECT *
FROM BOOK
ORDER BY CASE TITLE
         WHEN '1984' THEN 0
         WHEN 'Animal Farm' THEN 1
         ELSE 2 END ASC
 
create.select()
      .from(BOOK)
      .orderBy(choose(BOOK.TITLE)
               .when("1984", 0)
               .when("Animal Farm", 1)
               .otherwise(2).asc())
      .fetch();

But writing these things can become quite verbose. jOOQ supports a convenient syntax for specifying sort mappings. The same query can be written in jOOQ as such:

create.select()
      .from(BOOK)
      .orderBy(BOOK.TITLE.sortAsc("1984", "Animal Farm"))
      .fetch();

More complex sort indirections can be provided using a Map:

create.select()
      .from(BOOK)
      .orderBy(BOOK.TITLE.sort(new HashMap<String, Integer>() {{
          put("1984", 1);
          put("Animal Farm", 13);
          put("The jOOQ book", 10);
      }}))
      .fetch();

Of course, you can combine this feature with the previously discussed NULLS FIRST / NULLS LAST feature. So, if in fact these two books are the ones you like least, you can put all NULLS FIRST (all the other books):

create.select()
      .from(BOOK)
      .orderBy(BOOK.TITLE.sortAsc("1984", "Animal Farm").nullsFirst())
      .fetch();

jOOQ's understanding of SELECT .. ORDER BY

The SQL standard defines that a "query expression" can be ordered, and that query expressions can contain UNION, INTERSECT and EXCEPT clauses, whose subqueries cannot be ordered. While this is defined as such in the SQL standard, many databases allowing for the LIMIT clause in one way or another, do not adhere to this part of the SQL standard. Hence, jOOQ allows for ordering all SELECT statements, regardless whether they are constructed as a part of a UNION or not. Corner-cases are handled internally by jOOQ, by introducing synthetic subselects to adhere to the correct syntax, where this is needed.

Oracle's ORDER SIBLINGS BY clause

jOOQ also supports Oracle's SIBLINGS keyword to be used with ORDER BY clauses for hierarchical queries using CONNECT BY

 

4.3.4.10. LIMIT .. OFFSET clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

While being extremely useful for every application that does pagination, or just to limit result sets to reasonable sizes, this clause has not been standardised up until SQL:2008. Hence, there exist a variety of possible implementations in various SQL dialects, concerning this limit clause. jOOQ chose to implement the LIMIT .. OFFSET clause as understood and supported by MySQL, H2, HSQLDB, Postgres, and SQLite. Here is an example of how to apply limits with jOOQ:

create.select().from(BOOK).orderBy(BOOK.ID).limit(1).offset(2).fetch();

This will limit the result to 1 books skipping the first 2 books (offset 2). limit() is supported in all dialects, offset() in all but Sybase ASE, which has no reasonable means to emulate it. This is how jOOQ trivially emulates the above query in various SQL dialects with native OFFSET pagination support:

-- MySQL, H2, HSQLDB, Postgres, and SQLite
SELECT * FROM BOOK ORDER BY ID LIMIT 1 OFFSET 2

-- CUBRID supports a MySQL variant of the LIMIT .. OFFSET clause
SELECT * FROM BOOK LIMIT 2, 1

-- Derby, SQL Server 2012, Oracle 12c, the SQL:2008 standard
SELECT * FROM BOOK ORDER BY ID OFFSET 2 ROWS FETCH NEXT 1 ROWS ONLY

-- Informix has SKIP .. FIRST support
SELECT SKIP 2 FIRST 1 * FROM BOOK ORDER BY ID

-- Ingres (almost the SQL:2008 standard)
SELECT * FROM BOOK ORDER BY ID OFFSET 2 FETCH FIRST 1 ROWS ONLY

-- Firebird
SELECT * FROM BOOK ORDER BY ID ROWS 2 TO 3

-- Sybase SQL Anywhere
SELECT TOP 1 START AT 3 * FROM BOOK ORDER BY ID

-- DB2 (almost the SQL:2008 standard, without OFFSET)
SELECT * FROM BOOK ORDER BY ID FETCH FIRST 1 ROWS ONLY

-- Sybase ASE, SQL Server 2008 (without OFFSET)
SELECT TOP 1 * FROM BOOK ORDER BY ID

Things get a little more tricky in those databases that have no native idiom for OFFSET pagination (actual queries may vary):

-- DB2 (with OFFSET), SQL Server 2008 (with OFFSET)
SELECT * FROM (
  SELECT BOOK.*,
    ROW_NUMBER() OVER (ORDER BY ID ASC) AS RN
  FROM BOOK
) AS X
WHERE RN > 2
AND RN <= 3

-- DB2 (with OFFSET), SQL Server 2008 (with OFFSET)
SELECT * FROM (
  SELECT DISTINCT BOOK.ID, BOOK.TITLE,
    DENSE_RANK() OVER (ORDER BY ID ASC, TITLE ASC) AS RN
  FROM BOOK
) AS X
WHERE RN > 2
AND RN <= 3

-- Oracle 11g and less
SELECT *
FROM (
  SELECT b.*, ROWNUM RN
  FROM (
    SELECT *
    FROM BOOK
    ORDER BY ID ASC
  ) b
  WHERE ROWNUM <= 3
)
WHERE RN > 2

As you can see, jOOQ will take care of the incredibly painful ROW_NUMBER() OVER() (or ROWNUM for Oracle) filtering in subselects for you, you'll just have to write limit(1).offset(2) in any dialect.

SQL Server's ORDER BY, TOP and subqueries

As can be seen in the above example, writing correct SQL can be quite tricky, depending on the SQL dialect. For instance, with SQL Server, you cannot have an ORDER BY clause in a subquery, unless you also have a TOP clause. This is illustrated by the fact that jOOQ renders a TOP 100 PERCENT clause for you. The same applies to the fact that ROW_NUMBER() OVER() needs an ORDER BY windowing clause, even if you don't provide one to the jOOQ query. By default, jOOQ adds ordering by the first column of your projection.

Keyset pagination

Note, the LIMIT clause can also be used with the SEEK clause for keyset pagination.

 

4.3.4.11. SEEK clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

One of the previous chapters talked about OFFSET pagination using LIMIT .. OFFSET, or OFFSET .. FETCH or some other vendor-specific variant of the same. This can lead to significant performance issues when reaching a high page number, as all unneeded records need to be skipped by the database.

A much faster and more stable way to perform pagination is the so-called keyset pagination method also called seek method. jOOQ supports a synthetic seek() clause, that can be used to perform keyset pagination (learn about other synthetic sql syntaxes). Imagine we have these data:

|   ID | VALUE | PAGE_BOUNDARY |
|------|-------|---------------|
|  ... |   ... |           ... |
|  474 |     2 |             0 |
|  533 |     2 |             1 | <-- Before page 6
|  640 |     2 |             0 |
|  776 |     2 |             0 |
|  815 |     2 |             0 |
|  947 |     2 |             0 |
|   37 |     3 |             1 | <-- Last on page 6
|  287 |     3 |             0 |
|  450 |     3 |             0 |
|  ... |   ... |           ... |

Now, if we want to display page 6 to the user, instead of going to page 6 by using a record OFFSET, we could just fetch the record strictly after the last record on page 5, which yields the values (533, 2). This is how you would do it with SQL or with jOOQ:


SELECT id, value
FROM t
WHERE (value, id) > (2, 533)
ORDER BY value, id
LIMIT 5
 
DSL.using(configuration)
   .select(T.ID, T.VALUE)
   .from(T)
   .orderBy(T.VALUE, T.ID)
   .seek(lastValue, lastId) // from last page: value = 2, id = 533
   .limit(5)
   .fetch();

As you can see, the jOOQ SEEK clause is a synthetic clause that does not really exist in SQL. However, the jOOQ syntax is far more intuitive for a variety of reasons:

  • It replaces OFFSET where you would expect
  • It doesn't force you to mix regular predicates with "seek" predicates
  • It is typesafe
  • It emulates row value expression predicates for you, in those databases that do not support them

This query now yields:

|  ID | VALUE |
|-----|-------|
| 640 |     2 |
| 776 |     2 |
| 815 |     2 |
| 947 |     2 |
|  37 |     3 |

Note that you cannot combine the SEEK clause with the OFFSET clause.

More information about this great feature can be found in the jOOQ blog:

Further information about offset pagination vs. keyset pagination performance can be found on our partner page:

 

4.3.4.12. FOR UPDATE clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For inter-process synchronisation and other reasons, you may choose to use the SELECT .. FOR UPDATE clause to indicate to the database, that a set of cells or records should be locked by a given transaction for subsequent updates. With jOOQ, this can be achieved as such:

SELECT *
FROM BOOK
WHERE ID = 3
FOR UPDATE
 
create.select()
      .from(BOOK)
      .where(BOOK.ID.eq(3))
      .forUpdate()
      .fetch();

The above example will produce a record-lock, locking the whole record for updates. Some databases also support cell-locks using FOR UPDATE OF ..

SELECT *
FROM BOOK
WHERE ID = 3
FOR UPDATE OF TITLE
 
create.select()
      .from(BOOK)
      .where(BOOK.ID.eq(3))
      .forUpdate().of(BOOK.TITLE)
      .fetch();

Oracle goes a bit further and also allows to specify the actual locking behaviour. It features these additional clauses, which are all supported by jOOQ:

  • FOR UPDATE NOWAIT: This is the default behaviour. If the lock cannot be acquired, the query fails immediately
  • FOR UPDATE WAIT n: Try to wait for [n] seconds for the lock acquisition. The query will fail only afterwards
  • FOR UPDATE SKIP LOCKED: This peculiar syntax will skip all locked records. This is particularly useful when implementing queue tables with multiple consumers

With jOOQ, you can use those Oracle extensions as such:

create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().nowait().fetch();
create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().wait(5).fetch();
create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().skipLocked().fetch();

FOR UPDATE in CUBRID and SQL Server

The SQL standard specifies a FOR UPDATE clause to be applicable for cursors. Most databases interpret this as being applicable for all SELECT statements. An exception to this rule are the CUBRID and SQL Server databases, that do not allow for any FOR UPDATE clause in a regular SQL SELECT statement. jOOQ emulates the FOR UPDATE behaviour, by locking record by record with JDBC. JDBC allows for specifying the flags TYPE_SCROLL_SENSITIVE, CONCUR_UPDATABLE for any statement, and then using ResultSet.updateXXX() methods to produce a cell-lock / row-lock. Here's a simplified example in JDBC:

try (
    PreparedStatement stmt = connection.prepareStatement(
        "SELECT * FROM author WHERE id IN (3, 4, 5)",
        ResultSet.TYPE_SCROLL_SENSITIVE,
        ResultSet.CONCUR_UPDATABLE);
    ResultSet rs = stmt.executeQuery()
) {
    while (rs.next()) {
        // UPDATE the primary key for row-locks, or any other columns for cell-locks
        rs.updateObject(1, rs.getObject(1));
        rs.updateRow();

        // Do more stuff with this record
    }
}

The main drawback of this approach is the fact that the database has to maintain a scrollable cursor, whose records are locked one by one. This can cause a major risk of deadlocks or race conditions if the JDBC driver can recover from the unsuccessful locking, if two Java threads execute the following statements:

-- thread 1
SELECT * FROM author ORDER BY id ASC;

-- thread 2
SELECT * FROM author ORDER BY id DESC;

So use this technique with care, possibly only ever locking single rows!

Pessimistic (shared) locking with the FOR SHARE clause

Some databases (MySQL, Postgres) also allow to issue a non-exclusive lock explicitly using a FOR SHARE clause. This is also supported by jOOQ

Optimistic locking in jOOQ

Note, that jOOQ also supports optimistic locking, if you're doing simple CRUD. This is documented in the section's manual about optimistic locking.

 

4.3.4.13. Set operations

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

SQL allows to perform set operations as understood in standard set theory on result sets. These operations include unions, intersections, subtractions. For two subselects to be combinable by such a set operator, each subselect must return a table expression of the same degree and type.

All of these set operations come with 2 flavours:

  • DISTINCT (the default): Removing duplicates after applying the set operation
  • ALL: Retaining duplicates after applying the set operation
 

4.3.4.13.1. Type safety

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Two subselects of degree less than 22 that are combined by a set operator are required to be of the same degree and, in most databases, also of the same type. jOOQ 3.0's introduction of Typesafe Record[N] types helps compile-checking these constraints:

// Some sample SELECT statements
Select<Record2<Integer, String>>  s1 = select(BOOK.ID, BOOK.TITLE).from(BOOK);
Select<Record1<Integer>>          s2 = selectOne();
Select<Record2<Integer, Integer>> s3 = select(one(), zero());
Select<Record2<Integer, String>>  s4 = select(one(), inline("abc"));

// Let's try to combine them:
s1.union(s2); // Doesn't compile because of a degree mismatch. Expected: Record2<...>, got: Record1<...>
s1.union(s3); // Doesn't compile because of a type mismatch. Expected: <Integer, String>, got: <Integer, Integer>
s1.union(s4); // OK. The two Record[N] types match
 

4.3.4.13.2. Projection rowtype

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Much like most dialects use only the first set operation subquery's column names and types for the resulting row type, so does jOOQ.

Since jOOQ does not know which row is produced by which union subquery, it cannot disambiguate these rows in case the projection row type isn't exactly identical. As such, the ad-hoc converter in the following example is ignored:

Result<Record1<Integer>> result =
create.select(BOOK.ID)
   .from(BOOK)
   .union(

    // This has no effect
    select(AUTHOR.ID.convertFrom(i -> -i))
   .from(AUTHOR))
   .fetch();

While this can lead to subtle bugs, it makes perfect sense, knowing that a Converter is always applied at the client side of the execution.

 

4.3.4.13.3. Differences to standard SQL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

As previously mentioned in the manual's section about the ORDER BY clause, jOOQ has slightly changed the semantics of these set operators. While in SQL, a set operation subselect may not immediately contain any ORDER BY clause or LIMIT clause (unless you wrap the subselect into a derived table), jOOQ allows you to do so. In order to select both the youngest and the oldest author from the database, you can issue the following statement with jOOQ (rendered to the MySQL dialect):

  (SELECT * FROM AUTHOR
   ORDER BY DATE_OF_BIRTH ASC LIMIT 1)
UNION
  (SELECT * FROM AUTHOR
   ORDER BY DATE_OF_BIRTH DESC LIMIT 1)
ORDER BY 1
 
create.selectFrom(AUTHOR)
      .orderBy(AUTHOR.DATE_OF_BIRTH.asc()).limit(1)
      .union(
       selectFrom(AUTHOR)
      .orderBy(AUTHOR.DATE_OF_BIRTH.desc()).limit(1))
      .orderBy(1)
      .fetch();

In case your database doesn't support ordered UNION subselects, the subselects are nested in derived tables.

SELECT * FROM (
  SELECT * FROM AUTHOR
  ORDER BY DATE_OF_BIRTH ASC LIMIT 1
)
UNION
SELECT * FROM (
  SELECT * FROM AUTHOR
  ORDER BY DATE_OF_BIRTH DESC LIMIT 1
)
ORDER BY 1

Dialect support

This example using jOOQ:

select(BOOK.ID).from(BOOK).orderBy(BOOK.ID).limit(1).union(select(AUTHOR.ID).from(AUTHOR).orderBy(AUTHOR.ID).limit(1)).orderBy(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, SQLDATAWAREHOUSE, SYBASE
(
  SELECT TOP 1 BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
)
UNION (
  SELECT TOP 1 AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
)
ORDER BY 1

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, HANA, HSQLDB, MYSQL, REDSHIFT, SNOWFLAKE, VERTICA, 
-- YUGABYTEDB
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  LIMIT 1
)
UNION (
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  LIMIT 1
)
ORDER BY 1

-- BIGQUERY
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  LIMIT 1
)
UNION DISTINCT (
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  LIMIT 1
)
ORDER BY 1

-- DB2
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
)
UNION (
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  FETCH NEXT 1 ROWS ONLY
)
ORDER BY 1

-- DERBY, H2, MARIADB, ORACLE, POSTGRES, TRINO
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  FETCH NEXT 1 ROWS ONLY
)
UNION (
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  FETCH NEXT 1 ROWS ONLY
)
ORDER BY 1

-- FIREBIRD

  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  FETCH NEXT 1 ROWS ONLY
UNION 
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  FETCH NEXT 1 ROWS ONLY
ORDER BY 1

-- INFORMIX
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
)
UNION (
  SELECT *
  FROM (
    SELECT FIRST 1 AUTHOR.ID
    FROM AUTHOR
    ORDER BY AUTHOR.ID
  ) x
)
ORDER BY 1

-- MEMSQL
SELECT 
  t.*
FROM (
  (
    SELECT BOOK.ID
    FROM BOOK
    ORDER BY BOOK.ID
    LIMIT 1
  )
  UNION (
    SELECT AUTHOR.ID
    FROM AUTHOR
    ORDER BY AUTHOR.ID
    LIMIT 1
  )
) t
ORDER BY 1

-- SQLITE

SELECT *
FROM (
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  LIMIT 1
) x
UNION 
SELECT *
FROM (
  SELECT AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
  LIMIT 1
) x
ORDER BY 1

-- SQLSERVER
(
  SELECT TOP 1 BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
  OFFSET 0 ROWS
  FETCH NEXT 1 ROWS ONLY
)
UNION (
  SELECT TOP 1 AUTHOR.ID
  FROM AUTHOR
  ORDER BY AUTHOR.ID
)
ORDER BY 1

-- TERADATA
(
  SELECT BOOK.ID
  FROM BOOK
  ORDER BY BOOK.ID
)
UNION (
  SELECT *
  FROM (
    SELECT TOP 1 AUTHOR.ID
    FROM AUTHOR
    ORDER BY AUTHOR.ID
  ) x
)
ORDER BY 1
 

4.3.4.13.4. UNION

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A UNION operation combines two subquery results of compatible row type into a single result. While UNION removes all duplicate records resulting from this combination, UNION ALL leaves subselect results as they are. Typically, you should prefer UNION ALL over UNION, if you don't really need to remove duplicates, see also this section of the manual. The following example shows how to use such a UNION operation in jOOQ.

SELECT * FROM BOOK WHERE ID = 3
UNION ALL
SELECT * FROM BOOK WHERE ID = 5
 
create.selectFrom(BOOK).where(BOOK.ID.eq(3))
      .unionAll(
create.selectFrom(BOOK).where(BOOK.ID.eq(5)))
      .fetch();

Dialect support

This example using jOOQ:

select(BOOK.ID).from(BOOK).union(select(AUTHOR.ID).from(AUTHOR)).orderBy(BOOK.ID)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, 
-- YUGABYTEDB
SELECT BOOK.ID
FROM BOOK
UNION
SELECT AUTHOR.ID
FROM AUTHOR
ORDER BY ID

-- BIGQUERY
SELECT BOOK.ID
FROM BOOK
UNION DISTINCT
SELECT AUTHOR.ID
FROM AUTHOR
ORDER BY ID

-- FIREBIRD
SELECT BOOK.ID
FROM BOOK
UNION
SELECT AUTHOR.ID
FROM AUTHOR
ORDER BY 1

-- MEMSQL
SELECT 
  t.*
FROM (
  SELECT BOOK.ID
  FROM BOOK
  UNION
  SELECT AUTHOR.ID
  FROM AUTHOR
) t
ORDER BY ID
 

4.3.4.13.5. INTERSECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

INTERSECT is the operation that produces only those values that are returned by both subselects. By default, this removes duplicate rows. Use INTERSECT ALL in order to retain them, and require duplicates to appear in both subqueries.

SELECT ID FROM BOOK
INTERSECT ALL
SELECT ID FROM AUTHOR
 
create.select(BOOK.ID).from(BOOK)
      .intersectAll(
create.select(AUTHOR.ID).from(AUTHOR))
      .fetch();

Dialect support

This example using jOOQ:

select(BOOK.ID).from(BOOK).intersect(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, ORACLE, POSTGRES, 
-- SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
SELECT BOOK.ID
FROM BOOK
INTERSECT
SELECT AUTHOR.ID
FROM AUTHOR
ORDER BY ID

-- BIGQUERY
SELECT BOOK.ID
FROM BOOK
INTERSECT DISTINCT
SELECT AUTHOR.ID
FROM AUTHOR
ORDER BY ID

-- MEMSQL
SELECT 
  t.*
FROM (
  SELECT BOOK.ID
  FROM BOOK
  INTERSECT
  SELECT AUTHOR.ID
  FROM AUTHOR
) t
ORDER BY ID

-- ACCESS, AURORA_MYSQL, DUCKDB, FIREBIRD, REDSHIFT
/* UNSUPPORTED */
 

4.3.4.13.6. 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 */
 

4.3.4.14. Lexical and logical SELECT clause order

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

SQL has a lexical and a logical order of SELECT clauses. The lexical order of SELECT clauses is inspired by the English language. As SQL statements are commands for the database, it is natural to express a statement in an imperative tense, such as "SELECT this and that!".

Logical SELECT clause order

The logical order of SELECT clauses, however, does not correspond to the syntax. In fact, the logical order is this:

The SQL Server documentation also explains this, with slightly different clauses:

  • FROM
  • ON
  • JOIN
  • WHERE
  • GROUP BY
  • WITH CUBE or WITH ROLLUP
  • HAVING
  • SELECT
  • DISTINCT
  • ORDER BY
  • TOP

As can be seen, databases have to logically reorder a SQL statement in order to determine the best execution plan.

Alternative syntaxes: LINQ, SLICK

Some "higher-level" abstractions, such as C#'s LINQ or Scala's SLICK try to inverse the lexical order of SELECT clauses to what appears to be closer to the logical order. The obvious advantage of moving the SELECT clause to the end is the fact that the projection type, which is the record type returned by the SELECT statement can be re-used more easily in the target environment of the internal domain specific language.

A LINQ example:

// LINQ-to-SQL looks somewhat similar to SQL
// AS clause    // FROM clause
From p          In db.Products

// WHERE clause
Where p.UnitsInStock <= p.ReorderLevel AndAlso Not p.Discontinued

// SELECT clause
Select p

A SLICK example:

// "for" is the "entry-point" to the DSL
val q = for {

    // FROM clause   WHERE clause
    c <- Coffees     if c.supID === 101

// SELECT clause and projection to a tuple
} yield (c.name, c.price)

While this looks like a good idea at first, it only complicates translation to more advanced SQL statements while impairing readability for those users that are used to writing SQL. jOOQ is designed to look just like SQL. This is specifically true for SLICK, which not only changed the SELECT clause order, but also heavily "integrated" SQL clauses with the Scala language.

For these reasons, the jOOQ DSL API is modelled in SQL's lexical order.

 

4.3.5. The INSERT statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The INSERT statement is used to insert new records into a database table. The following sections describe the various operation modes of the jOOQ INSERT statement.

 

4.3.5.1. INSERT .. VALUES

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

INSERT .. VALUES with a single row

Records can either be supplied using a VALUES() constructor, or a SELECT statement. jOOQ supports both types of INSERT statements. An example of an INSERT statement using a VALUES() constructor is given here:

INSERT INTO AUTHOR
       (ID, FIRST_NAME, LAST_NAME)
VALUES (100, 'Hermann', 'Hesse');
 
create.insertInto(AUTHOR,
        AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values(100, "Hermann", "Hesse")
      .execute();

Note that for explicit degrees up to 22, the VALUES() constructor provides additional typesafety. The following example illustrates this:

InsertValuesStep3<AuthorRecord, Integer, String, String> step =
  create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME);
    step.values("A", "B", "C");
         // ^^^ Doesn't compile, the expected type is Integer

INSERT .. VALUES with multiple rows

The SQL standard specifies that multiple rows can be supplied to the VALUES() constructor in an INSERT statement. Here's an example of a multi-record INSERT

INSERT INTO AUTHOR
       (ID, FIRST_NAME, LAST_NAME)
VALUES (100, 'Hermann', 'Hesse'),
       (101, 'Alfred', 'Döblin');
 
create.insertInto(AUTHOR,
        AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values(100, "Hermann", "Hesse")
      .values(101, "Alfred", "Döblin")
      .execute()

jOOQ tries to stay close to actual SQL. In detail, however, Java's expressiveness is limited. That's why the values() clause is repeated for every record in multi-record inserts.

Some RDBMS do not support inserting several records in a single statement. In those cases, jOOQ emulates multi-record INSERTs using the following SQL:

INSERT INTO AUTHOR
    (ID, FIRST_NAME, LAST_NAME)
SELECT 100, 'Hermann', 'Hesse' FROM DUAL UNION ALL
SELECT 101, 'Alfred', 'Döblin' FROM DUAL;
 
create.insertInto(AUTHOR,
        AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values(100, "Hermann", "Hesse")
      .values(101, "Alfred", "Döblin")
      .execute();
 

4.3.5.2. INSERT .. DEFAULT VALUES

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A lesser-known syntactic feature of SQL is the INSERT .. DEFAULT VALUES statement, where a single record is inserted, containing only DEFAULT values for every row. It is written as such:

INSERT INTO AUTHOR
DEFAULT VALUES;
 
create.insertInto(AUTHOR)
      .defaultValues()
      .execute();

This can make a lot of sense in situations where you want to "reserve" a row in the database for an subsequent UPDATE statement within the same transaction. Or if you just want to send an event containing trigger-generated default values, such as IDs or timestamps.

The DEFAULT VALUES clause is not supported in all databases, but jOOQ can emulate it using the equivalent statement:

INSERT INTO AUTHOR
    (ID, FIRST_NAME, LAST_NAME, ...)
VALUES (
	DEFAULT,
	DEFAULT,
	DEFAULT, ...);
 
create.insertInto(
        AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, ...)
      .values(
      	defaultValue(AUTHOR.ID),
      	defaultValue(AUTHOR.FIRST_NAME),
      	defaultValue(AUTHOR.LAST_NAME), ...)
      .execute();

The DEFAULT keyword (or DSL#defaultValue() method) can also be used for individual columns only, although that will have the same effect as leaving the column away entirely.

 

4.3.5.3. INSERT .. SET

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

MySQL (and some other RDBMS) allow for using a non-SQL-standard, UPDATE-like syntax for INSERT statements. This is also supported in jOOQ (and emulated for all databases), should you prefer that syntax. The above INSERT statement can also be expressed as follows:

create.insertInto(AUTHOR)
      .set(AUTHOR.ID, 100)
      .set(AUTHOR.FIRST_NAME, "Hermann")
      .set(AUTHOR.LAST_NAME, "Hesse")
      .newRecord()
      .set(AUTHOR.ID, 101)
      .set(AUTHOR.FIRST_NAME, "Alfred")
      .set(AUTHOR.LAST_NAME, "Döblin")
      .execute();

As you can see, this syntax is a bit more verbose, but also more readable, as every field can be matched with its value. Internally, the two syntaxes are strictly equivalent.

 

4.3.5.4. INSERT .. SELECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In some occasions, you may prefer the INSERT SELECT syntax, for instance, when you copy records from one table to another:

create.insertInto(AUTHOR_ARCHIVE)
      .select(selectFrom(AUTHOR).where(AUTHOR.DECEASED.isTrue()))
      .execute();
 

4.3.5.5. INSERT .. ON DUPLICATE KEY UPDATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ON DUPLICATE KEY UPDATE clause

The MySQL database supports a very convenient way to INSERT or UPDATE a record. This is a non-standard extension to the SQL syntax, which is supported by jOOQ and emulated in other RDBMS, where this is possible (e.g. if they support the SQL standard MERGE statement). Here is an example how to use the ON DUPLICATE KEY UPDATE clause:

// Add a new author called "Koontz" with ID 3.
// If that ID is already present, update the author's name
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME)
      .values(3, "Koontz")
      .onDuplicateKeyUpdate()
      .set(AUTHOR.LAST_NAME, "Koontz")
      .execute();

Dialect support

This example using jOOQ:

insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onDuplicateKeyUpdate().set(AUTHOR.LAST_NAME, "X")

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
INSERT INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)
ON DUPLICATE KEY UPDATE
  AUTHOR.LAST_NAME = 'X'

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, YUGABYTEDB
INSERT INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)
ON CONFLICT (ID)
DO UPDATE
SET
  LAST_NAME = 'X'

-- DB2
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYSIBM.DUAL
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- DERBY
MERGE INTO AUTHOR
USING SYSIBM.SYSDUMMY1
ON AUTHOR.ID = 3
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)

-- EXASOL
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- FIREBIRD
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM RDB$DATABASE
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- H2
MERGE INTO AUTHOR
USING (
  SELECT
    3 ID,
    'X' LAST_NAME
) t
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HANA
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
    FROM SYS.DUMMY
  )
) t
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HSQLDB
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (VALUES(1)) AS dual(dual)
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- ORACLE
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
  )
) t
ON (AUTHOR.ID = t.ID)
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- SNOWFLAKE
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- SQLITE
INSERT INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)
ON CONFLICT 
DO UPDATE
SET
  LAST_NAME = 'X'

-- SQLSERVER
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
);

-- SYBASE
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYS.DUMMY
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- TERADATA
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (
    SELECT 1 AS "dual"
  ) AS "dual"
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- ACCESS, ASE, BIGQUERY, INFORMIX, REDSHIFT, SQLDATAWAREHOUSE, TRINO, VERTICA
/* UNSUPPORTED */
 

4.3.5.6. INSERT .. ON DUPLICATE KEY IGNORE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The MySQL database also supports an INSERT IGNORE INTO clause. This is supported by jOOQ using the more convenient SQL syntax variant of ON DUPLICATE KEY IGNORE:

// Add a new author called "Koontz" with ID 3.
// If that ID is already present, ignore the INSERT statement
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME)
      .values(3, "Koontz")
      .onDuplicateKeyIgnore()
      .execute();

If the underlying database doesn't have any way to "ignore" failing INSERT statements, (e.g. MySQL via INSERT IGNORE), jOOQ can emulate the statement using a MERGE statement, or using INSERT .. SELECT WHERE NOT EXISTS.

The MySQL INSERT IGNORE statement ignores more constraint violations than just duplicate keys, so the emulation isn't exactly equivalent, see #5211

Dialect support

This example using jOOQ:

insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onDuplicateKeyIgnore()

Translates to the following dialect specific expressions:

-- ACCESS
INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT t.v0, t.v1
FROM (
  SELECT
    3 v0,
    'X' v1
  FROM (
    SELECT count(*) dual
    FROM MSysResources
  ) AS dual
  WHERE NOT EXISTS (
    SELECT 1 one
    FROM AUTHOR
    WHERE AUTHOR.ID = 3
  )
) t

-- ASE, REDSHIFT, SQLDATAWAREHOUSE, TRINO, VERTICA
INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT t.v0, t.v1
FROM (
  SELECT
    3 v0,
    'X' v1
  WHERE NOT EXISTS (
    SELECT 1 one
    FROM AUTHOR
    WHERE AUTHOR.ID = 3
  )
) t

-- AURORA_MYSQL, MARIADB, MYSQL
INSERT IGNORE INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, SQLITE, YUGABYTEDB
INSERT INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)
ON CONFLICT
DO NOTHING

-- BIGQUERY
INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT t.v0, t.v1
FROM (
  SELECT
    3 v0,
    'X' v1
  FROM UNNEST([STRUCT(1 AS dual)]) AS dual
  WHERE NOT EXISTS (
    SELECT 1 one
    FROM AUTHOR
    WHERE AUTHOR.ID = 3
  )
) t

-- DB2
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYSIBM.DUAL
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- DERBY
MERGE INTO AUTHOR
USING SYSIBM.SYSDUMMY1
ON AUTHOR.ID = 3
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)

-- EXASOL, MEMSQL
INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT t.v0, t.v1
FROM (
  SELECT
    3 v0,
    'X' v1
  FROM DUAL
  WHERE NOT EXISTS (
    SELECT 1 one
    FROM AUTHOR
    WHERE AUTHOR.ID = 3
  )
) t

-- FIREBIRD
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM RDB$DATABASE
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- H2
MERGE INTO AUTHOR
USING (
  SELECT
    3 ID,
    'X' LAST_NAME
) t
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HANA
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
    FROM SYS.DUMMY
  )
) t
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HSQLDB
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (VALUES(1)) AS dual(dual)
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- INFORMIX
INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT t.v0, t.v1
FROM (
  SELECT
    3 v0,
    'X' v1
  FROM (
    SELECT 1 AS dual
    FROM systables
    WHERE (tabid = 1)
  ) AS dual
  WHERE NOT EXISTS (
    SELECT 1 one
    FROM AUTHOR
    WHERE AUTHOR.ID = 3
  )
) t

-- ORACLE
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
  )
) t
ON (AUTHOR.ID = t.ID)
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- SNOWFLAKE
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- SQLSERVER
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
);

-- SYBASE
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYS.DUMMY
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- TERADATA
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (
    SELECT 1 AS "dual"
  ) AS "dual"
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)
 

4.3.5.7. INSERT .. ON CONFLICT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The PostgreSQL database offers an alternative syntax to MySQL's vendor specific INSERT .. ON DUPLICATE KEY syntax, which allows for specifying an explicit (reference by constraint name) or implicit (reference by column list) unique constraint for conflict resolution.

// Add a new author called "Koontz" with ID 3.
// If that ID is already present, update the author's name
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME)
      .values(3, "Koontz")
      .onConflict(AUTHOR.ID)
      .doUpdate()
      .set(AUTHOR.LAST_NAME, "Koontz")
      .execute();

Dialect support

This example using jOOQ:

insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onConflict(AUTHOR.ID).doUpdate().set(AUTHOR.LAST_NAME, "X")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, SQLITE, YUGABYTEDB
INSERT INTO AUTHOR (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)
ON CONFLICT (ID)
DO UPDATE
SET
  LAST_NAME = 'X'

-- DB2
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYSIBM.DUAL
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- DERBY
MERGE INTO AUTHOR
USING SYSIBM.SYSDUMMY1
ON AUTHOR.ID = 3
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  3, 
  'X'
)

-- EXASOL
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- FIREBIRD
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM RDB$DATABASE
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- H2
MERGE INTO AUTHOR
USING (
  SELECT
    3 ID,
    'X' LAST_NAME
) t
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HANA
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
    FROM SYS.DUMMY
  )
) t
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- HSQLDB
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (VALUES(1)) AS dual(dual)
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- ORACLE
MERGE INTO AUTHOR
USING (
  (
    SELECT
      3 ID,
      'X' LAST_NAME
  )
) t
ON (AUTHOR.ID = t.ID)
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- SQLSERVER
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
);

-- SYBASE
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM SYS.DUMMY
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  AUTHOR.LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- TERADATA
MERGE INTO AUTHOR
USING (
  SELECT 3, 'X'
  FROM (
    SELECT 1 AS "dual"
  ) AS "dual"
) t (ID, LAST_NAME)
ON AUTHOR.ID = t.ID
WHEN MATCHED THEN UPDATE SET
  LAST_NAME = 'X'
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
VALUES (
  t.ID, 
  t.LAST_NAME
)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, TRINO, 
-- VERTICA
/* UNSUPPORTED */
 

4.3.5.8. INSERT .. RETURNING

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The Postgres database has native support for an INSERT .. RETURNING clause. This is a very powerful concept that is emulated for all other dialects using JDBC's getGeneratedKeys() method. Take this example:

// Add another author, with a generated ID
Record record =
create.insertInto(AUTHOR, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values("Charlotte", "Roche")
      .returning(AUTHOR.ID)
      .fetchOne();

System.out.println(record.getValue(AUTHOR.ID));

// For some RDBMS, this also works when inserting several values
// The following should return a 2x2 table
Result<?> result =
create.insertInto(AUTHOR, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values("Johann Wolfgang", "von Goethe")
      .values("Friedrich", "Schiller")
      // You can request any field. Also trigger-generated values
      .returning(AUTHOR.ID, AUTHOR.CREATION_DATE)
      .fetch();

Some databases have poor support for returning generated keys after INSERTs. In those cases, jOOQ might need to issue another SELECT statement in order to fetch an @@identity value. Be aware, that this can lead to race-conditions in those databases that cannot properly return generated ID values. For more information, please consider the jOOQ Javadoc for the returning() clause.

Dialect support

This example using jOOQ:

insertInto(AUTHOR, AUTHOR.LAST_NAME).values("Doe").returningResult(AUTHOR.ID)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, 
-- SYBASE, TERADATA, TRINO, VERTICA
INSERT INTO AUTHOR (LAST_NAME)
VALUES ('Doe')

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, FIREBIRD, POSTGRES, SQLITE, YUGABYTEDB
INSERT INTO AUTHOR (LAST_NAME)
VALUES ('Doe')
RETURNING AUTHOR.ID

-- DB2, H2
SELECT ID
FROM FINAL TABLE (
  INSERT INTO AUTHOR (LAST_NAME)
  VALUES ('Doe')
) AUTHOR

-- MARIADB
INSERT INTO AUTHOR (LAST_NAME)
VALUES ('Doe')
RETURNING ID

-- SQLDATAWAREHOUSE, SQLSERVER
INSERT INTO AUTHOR (LAST_NAME)
OUTPUT inserted.ID
VALUES ('Doe')
 

4.3.6. The UPDATE statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The UPDATE statement is used to modify one or several pre-existing records in a database table. UPDATE statements are only possible on single tables. Support for multi-table updates might be implemented in the future. An example update query is given here:

UPDATE AUTHOR
   SET FIRST_NAME = 'Hermann',
       LAST_NAME = 'Hesse'
 WHERE ID = 3;
 
create.update(AUTHOR)
      .set(AUTHOR.FIRST_NAME, "Hermann")
      .set(AUTHOR.LAST_NAME, "Hesse")
      .where(AUTHOR.ID.eq(3))
      .execute();

The following subsections discuss the various subclauses of the DELETE statement.

 

4.3.6.1. UPDATE .. SET

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SET clause allows for setting new values on updated records in a table.

Dialect support

This example using jOOQ:

update(BOOK).set(BOOK.TITLE, "New Title")

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title'

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA, YUGABYTEDB
UPDATE BOOK
SET
  TITLE = 'New Title'

-- BIGQUERY
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title'
WHERE TRUE

-- HANA
UPDATE BOOK
FROM BOOK
SET
  BOOK.TITLE = 'New Title'
 

4.3.6.2. UPDATE .. SET ROWS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SET clause allows for setting ROW value expressions on updated records in a table.

UPDATE AUTHOR
   SET (FIRST_NAME, LAST_NAME) =
       ('Hermann',  'Hesse')
 WHERE ID = 3;
 
create.update(AUTHOR)
      .set(row(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME),
           row("Herman",          "Hesse"))
      .where(AUTHOR.ID.eq(3))
      .execute();

This can be particularly useful when using correlated subqueries in the SET clause, in case of which multiple columns can be updated with a single subquery, instead of only 1. See also UPDATE .. FROM for an alternative syntax for this scenario.

UPDATE AUTHOR
   SET (FIRST_NAME, LAST_NAME) = (
         SELECT PERSON.FIRST_NAME, PERSON.LAST_NAME
         FROM PERSON
         WHERE PERSON.ID = AUTHOR.ID
       )
 WHERE ID = 3;
 
create.update(AUTHOR)
      .set(row(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME),
           select(PERSON.FIRST_NAME, PERSON.LAST_NAME)
          .from(PERSON)
          .where(PERSON.ID.eq(AUTHOR.ID))
      )
      .where(AUTHOR.ID.eq(3))
      .execute();

The above row value expressions usages are completely typesafe.

Dialect support

This example using jOOQ:

update(BOOK).set(row(BOOK.TITLE, BOOK.LANGUAGE_ID), row("New Title", 1))

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, DERBY, EXASOL, FIREBIRD, INFORMIX, MARIADB, MEMSQL, MYSQL, SQLDATAWAREHOUSE, SQLSERVER, 
-- SYBASE
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title',
  BOOK.LANGUAGE_ID = 1

-- AURORA_POSTGRES, COCKROACHDB, DB2, H2, HSQLDB, TRINO
UPDATE BOOK
SET
  (TITLE, LANGUAGE_ID) = ('New Title', 1)

-- BIGQUERY
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title',
  BOOK.LANGUAGE_ID = 1
WHERE TRUE

-- DUCKDB, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA
UPDATE BOOK
SET
  TITLE = 'New Title',
  LANGUAGE_ID = 1

-- HANA
UPDATE BOOK
FROM BOOK
SET
  (TITLE, LANGUAGE_ID) = ('New Title', 1)

-- ORACLE
UPDATE BOOK
SET
  (TITLE, LANGUAGE_ID) = (
    SELECT 'New Title', 1
  )

-- POSTGRES, YUGABYTEDB
UPDATE BOOK
SET
  (TITLE, LANGUAGE_ID) = ROW ('New Title', 1)
 

4.3.6.3. UPDATE .. FROM

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some databases, including for example PostgreSQL and SQL Server, support joining additional tables to an UPDATE statement using a vendor-specific FROM clause. This is supported as well by jOOQ:

UPDATE BOOK_ARCHIVE
SET
  BOOK_ARCHIVE.TITLE = BOOK.TITLE
FROM BOOK
WHERE BOOK_ARCHIVE.ID = BOOK.ID
create.update(BOOK_ARCHIVE)
      .set(BOOK_ARCHIVE.TITLE, BOOK.TITLE)
      .from(BOOK)
      .where(BOOK_ARCHIVE.ID.eq(BOOK.ID))
      .execute();

In many cases, such a joined update statement can be emulated using a correlated subquery, or using updatable views. For example, most databases allow for using scalar subselects in UPDATE statements in one way or another. jOOQ models this through a set(Field<T>, Select<? extends Record1<T>>) method in the UPDATE DSL API, for convenience (see the section about scalar subqueries for more details):

UPDATE AUTHOR
   SET FIRST_NAME = (
         SELECT FIRST_NAME
         FROM PERSON
         WHERE PERSON.ID = AUTHOR.ID
       ),
 WHERE ID = 3;
 
create.update(AUTHOR)
      .set(AUTHOR.FIRST_NAME,
         select(PERSON.FIRST_NAME)
        .from(PERSON)
        .where(PERSON.ID.eq(AUTHOR.ID))
      )
      .where(AUTHOR.ID.eq(3))
      .execute();

Dialect support

This example using jOOQ:

update(BOOK_TO_BOOK_STORE).set(BOOK_TO_BOOK_STORE.STOCK, 0).from(BOOK).where(BOOK_TO_BOOK_STORE.BOOK_ID.eq(BOOK.ID)).and(BOOK.AUTHOR_ID.eq(1))

Translates to the following dialect specific expressions:

-- ASE, BIGQUERY, ORACLE, SQLSERVER, SYBASE
UPDATE BOOK_TO_BOOK_STORE
SET
  BOOK_TO_BOOK_STORE.STOCK = 0
FROM BOOK
WHERE (
  BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
  AND BOOK.AUTHOR_ID = 1
)

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, SNOWFLAKE, SQLITE
UPDATE BOOK_TO_BOOK_STORE
SET
  STOCK = 0
FROM BOOK
WHERE (
  BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
  AND BOOK.AUTHOR_ID = 1
)

-- DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB
MERGE INTO BOOK_TO_BOOK_STORE
USING BOOK
ON (
  BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
  AND BOOK.AUTHOR_ID = 1
)
WHEN MATCHED THEN UPDATE SET
  BOOK_TO_BOOK_STORE.STOCK = 0

-- HANA
UPDATE BOOK_TO_BOOK_STORE
FROM BOOK_TO_BOOK_STORE, BOOK
SET
  BOOK_TO_BOOK_STORE.STOCK = 0
WHERE (
  BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
  AND BOOK.AUTHOR_ID = 1
)

-- TERADATA, VERTICA
MERGE INTO BOOK_TO_BOOK_STORE
USING BOOK
ON (
  BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID
  AND BOOK.AUTHOR_ID = 1
)
WHEN MATCHED THEN UPDATE SET
  STOCK = 0

-- ACCESS, AURORA_MYSQL, DUCKDB, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.3.6.4. UPDATE .. WHERE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The WHERE clause allows for adding a conditional expressions to the UPDATE statement, which restricts the rows to be updated.

Dialect support

This example using jOOQ:

update(BOOK).set(BOOK.TITLE, "New Title").where(BOOK.ID.eq(1))

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, 
-- ORACLE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title'
WHERE BOOK.ID = 1

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA, YUGABYTEDB
UPDATE BOOK
SET
  TITLE = 'New Title'
WHERE BOOK.ID = 1

-- HANA
UPDATE BOOK
FROM BOOK
SET
  BOOK.TITLE = 'New Title'
WHERE BOOK.ID = 1
 

4.3.6.5. UPDATE .. RETURNING

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Various dialect support a RETURNING clause or something similar on their UPDATE statements, similar as the RETURNING clause in INSERT statements. This is useful to fetch trigger-generated values in one go. An example is given here:

-- Fetch a trigger-generated value
UPDATE BOOK
SET TITLE = 'Animal Farm'
WHERE ID = 5
RETURNING TITLE
String title = create.update(BOOK)
                  .set(BOOK.TITLE, "Animal Farm")
                  .where(BOOK.ID.eq(5))
                  .returning(BOOK.TITLE)
                  .fetchOne().getValue(BOOK.TITLE);

Dialect support

This example using jOOQ:

update(BOOK).set(BOOK.TITLE, "New Title").returningResult(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, SQLITE, YUGABYTEDB
UPDATE BOOK
SET
  TITLE = 'New Title'
RETURNING BOOK.ID

-- DB2, H2
SELECT ID
FROM FINAL TABLE (
  UPDATE BOOK
  SET
    BOOK.TITLE = 'New Title'
) BOOK

-- FIREBIRD
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title'
RETURNING BOOK.ID

-- MARIADB
INSERT INTO BOOK (
  ID,
  AUTHOR_ID,
  TITLE,
  PUBLISHED_IN,
  LANGUAGE_ID
)
SELECT
  BOOK.ID,
  BOOK.AUTHOR_ID,
  BOOK.TITLE,
  BOOK.PUBLISHED_IN,
  BOOK.LANGUAGE_ID
FROM BOOK
ON DUPLICATE KEY UPDATE
  BOOK.TITLE = 'New Title'
RETURNING ID

-- ORACLE
DECLARE
  o0 DBMS_SQL.NUMBER_TABLE;
  c0 sys_refcursor;
BEGIN
  UPDATE BOOK
  SET
    BOOK.TITLE = 'New Title'
  RETURNING BOOK.ID
  BULK COLLECT INTO o0;
  ? := SQL%ROWCOUNT;
  OPEN c0 FOR SELECT * FROM TABLE(o0);
  ? := c0;
END;

-- SQLSERVER
UPDATE BOOK
SET
  BOOK.TITLE = 'New Title'
OUTPUT inserted.ID

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.3.7. The DELETE statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DELETE statement removes records from a database table. DELETE statements are only possible on single tables. Support for multi-table deletes might be implemented in the future. An example delete query is given here:

DELETE AUTHOR
 WHERE ID = 100;
 
create.delete(AUTHOR)
      .where(AUTHOR.ID.eq(100))
      .execute();

The following subsections discuss the various subclauses of the DELETE statement.

 

4.3.7.1. DELETE .. WHERE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The WHERE clause allows for adding a conditional expressions to the DELETE statement, which restricts the rows to be deleted.

Dialect support

This example using jOOQ:

deleteFrom(BOOK).where(BOOK.ID.in(1, 2, 3))

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
DELETE FROM BOOK
WHERE BOOK.ID IN (
  1, 2, 3
)

-- BIGQUERY
DELETE FROM BOOK
WHERE (
  BOOK.ID IN (
    1, 2, 3
  )
  AND TRUE
)
 

4.3.7.2. DELETE .. RETURNING

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RETURNING clause allows for returning expressions based on the deleted rows.

Dialect support

This example using jOOQ:

deleteFrom(BOOK).where(BOOK.ID.eq(1)).returningResult(BOOK.TITLE)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, FIREBIRD, POSTGRES, SQLITE, YUGABYTEDB
DELETE FROM BOOK
WHERE BOOK.ID = 1
RETURNING BOOK.TITLE

-- DB2, H2
SELECT TITLE
FROM OLD TABLE (
  DELETE FROM BOOK
  WHERE BOOK.ID = 1
) BOOK

-- MARIADB
DELETE FROM BOOK
WHERE BOOK.ID = 1
RETURNING TITLE

-- ORACLE
DECLARE
  o0 DBMS_SQL.VARCHAR2_TABLE;
  c0 sys_refcursor;
BEGIN
  DELETE FROM BOOK
  WHERE BOOK.ID = 1
  RETURNING BOOK.TITLE
  BULK COLLECT INTO o0;
  ? := SQL%ROWCOUNT;
  OPEN c0 FOR SELECT * FROM TABLE(o0);
  ? := c0;
END;

-- SQLSERVER
DELETE FROM BOOK
OUTPUT deleted.TITLE
WHERE BOOK.ID = 1

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.3.8. The MERGE statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The MERGE statement is one of the most advanced standardised SQL constructs, which is supported by DB2, HSQLDB, Oracle, SQL Server and Sybase (MySQL has the similar INSERT .. ON DUPLICATE KEY UPDATE construct)

The point of the standard MERGE statement is to take a TARGET table, and merge (INSERT, UPDATE) data from a SOURCE table into it. DB2, Oracle, SQL Server and Sybase also allow for DELETING some data and for adding many additional clauses. With jOOQ 3.9.6, only Oracle's MERGE extensions are supported. Here is an example:

-- Check if there is already an author called 'Hitchcock'
-- If there is, rename him to John. If there isn't add him.
MERGE INTO AUTHOR
USING (SELECT 1 FROM DUAL)
ON (LAST_NAME = 'Hitchcock')
WHEN MATCHED THEN UPDATE SET FIRST_NAME = 'John'
WHEN NOT MATCHED THEN INSERT (LAST_NAME) VALUES ('Hitchcock');
 
create.mergeInto(AUTHOR)
      .using(create.selectOne())
      .on(AUTHOR.LAST_NAME.eq("Hitchcock"))
      .whenMatchedThenUpdate()
      .set(AUTHOR.FIRST_NAME, "John")
      .whenNotMatchedThenInsert(AUTHOR.LAST_NAME)
      .values("Hitchcock")
      .execute();

MERGE Statement (H2-specific syntax)

The H2 database ships with a somewhat less powerful but a little more intuitive syntax for its own version of the MERGE statement. An example more or less equivalent to the previous one can be seen here:

-- Check if there is already an author called 'Hitchcock'
-- If there is, rename him to John. If there isn't add him.

MERGE INTO AUTHOR (FIRST_NAME, LAST_NAME)
KEY (LAST_NAME)
VALUES ('John', 'Hitchcock')
create.mergeInto(AUTHOR,
                 AUTHOR.FIRST_NAME,
                 AUTHOR.LAST_NAME)
      .key(AUTHOR.LAST_NAME)
      .values("John", "Hitchcock")
      .execute();

This syntax can be fully emulated by jOOQ for all other databases that support the SQL standard MERGE statement. For more information about the H2 MERGE syntax, see the documentation here:
https://www.h2database.com/html/grammar.html#merge

Typesafety of VALUES() for degrees up to 22

Much like the INSERT statement, the MERGE statement's VALUES() clause provides typesafety for degrees up to 22, in both the standard syntax variant as well as the H2 variant.

 

4.4. SQL Statements (DDL)

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The Data Definition Language (DDL) is used to CREATE, ALTER, and DROP various object types in the database catalog. jOOQ supports an increasing number of these operations natively, and also adds synthetic operation support for convenience.

While many DDL statements are supported natively, and have a 1:1 correspondence to the jOOQ API's representation, dialects differ in many subtle ways when it comes to DDL statement support. These differences may include:

  • Different keywords to mean the same thing. For example, the keywords ALTER, CHANGE, or MODIFY may be used when altering columns or other attributes in a table.
  • Different statements instead of subclauses. For example, some dialects may choose to support RENAME [object type] .. TO .. statements instead of making the rename operation a subclause of ALTER [object type] .. RENAME TO ..
  • Some syntax may not be supported, or not be supported consistently, such as the various IF EXISTS and IF NOT EXISTS clauses. Emulations are possible using the dialect's procedural language

Because of these many differences, the jOOQ manual will not list each individual native SQL representation of each jOOQ API call. Also, some optional clauses may exist, such as the IF EXISTS or OR REPLACE clauses, which can easily be discovered from the API. The manual will omit documenting these clauses in every example.

 

4.4.1. The ALTER statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

ALTER statements are used to alter properties of existing objects in the database catalog.

 

4.4.1.1. ALTER INDEX

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The only property of an index that can be changed, currently, is its name. In order to alter an index's name, use:

// Renaming the index
create.alterIndex("old_index").renameTo("new_index").execute();
 

4.4.1.2. ALTER SCHEMA

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The only property of a schema that can be changed, currently, is its name. In order to alter an schema's name, use:

// Renaming the schema
create.alterSchema("old_schema").renameTo("new_schema").execute();

Dialect support

This example using jOOQ:

alterSchema("s").renameTo("t")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, POSTGRES, REDSHIFT, SNOWFLAKE, VERTICA
ALTER SCHEMA sRENAME TO t

-- HANA
RENAME SCHEMA sTO t

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, YUGABYTEDB
/* UNSUPPORTED */

IF EXISTS

A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS clause:

// Renaming the schema
create.alterSchemaIfExists("old_schema").renameTo("new_schema").execute();

Dialect support

This example using jOOQ:

alterSchemaIfExists("s").renameTo("t")

Translates to the following dialect specific expressions:

-- H2, SNOWFLAKE
ALTER SCHEMA IF EXISTS sRENAME TO t

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 362 BEGIN END;
  EXECUTE IMMEDIATE '
    RENAME SCHEMA sTO t
  ';
END;

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
/* UNSUPPORTED */
 

4.4.1.3. ALTER SEQUENCE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The following types of statements are supported when altering a sequence:

Alter sequence properties

jOOQ supports a variety of sequence properties through meta data and DDL.

// Let the sequence restart with MINVALUE or with a specific value
create.alterSequence(S_AUTHOR_ID).restart().execute();

RENAME

Like most object types, sequences can be renamed:

// Renaming the sequence
create.alterSequence("old_sequence").renameTo("new_sequence").execute();
 

4.4.1.4. ALTER TABLE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ALTER TABLE statement is certainly the most powerful among DDL statements, as tables are the most important object type in a database catalog. The following types of statements are supported when altering a table:

ADD

In most dialects, tables can contain two types of objects:

  • Columns
  • Constraints

These types of objects can be added to a table using the following API:

// Adding a single column to a table
create.alterTable("table").add("column", INTEGER).execute();

// Adding an unnamed constraint to a table
create.alterTable("table").add(primaryKey("id")).execute();
create.alterTable("table").add(unique("user_name")).execute();
create.alterTable("table").add(foreignKey("author_id").references("author")).execute();
create.alterTable("table").add(check(length(field(name("user_name"), VARCHAR)).gt(5))).execute();

// Adding a named constraint to a table
create.alterTable("table").add(constraint("pk").primaryKey("id")).execute();
create.alterTable("table").add(constraint("uk").unique("user_name")).execute();
create.alterTable("table").add(constraint("fk").foreignKey("author_id").references("author")).execute();
create.alterTable("table").add(constraint("ck").check(length(field(name("user_name"), VARCHAR)).gt(5))).execute();

There exists alternative API representing optional keywords, such as e.g. addColumn(), which have been omitted from the examples.

Note that some dialects also consider indexes to be a part of a table, but jOOQ does not yet support ALTER TABLE subclauses modifying indexes. Consider CREATE INDEX, ALTER INDEX, or DROP INDEX, instead.

ALTER

Both of the above objects can be altered in a table using the following API:

// Specify a new default value for a column
create.alterTable("table").alter("column").default_(1).execute();

// Set a new data type on the column
create.alterTable("table").alter("column").set(VARCHAR(50)).execute();

There exists alternative API representing optional keywords, such as e.g. alterColumn(), which have been omitted from the examples.

DROP

Both columns and constraints can also be dropped from tables using this API:

// Drop a single column
create.alterTable("table").drop("column").execute();

// Add CASCADE or RESTRICT clauses when dropping columns (or constraints)
create.alterTable("table").drop("column").cascade().execute();
create.alterTable("table").drop("column").restrict().execute();

// Drop a constraint
create.alterTable("table").dropConstraint("uk").execute();

RENAME

Like most object types, tables, columns, and constraints can be renamed:

// Rename a table
create.alterTable("old_table").renameTo("new_table").execute();

// Rename a column
create.alterTable("table").renameColumn("old_column").to("new_column").execute();

// Rename a constraint
create.alterTable("table").renameConstraint("old_constraint").to("new_constraint").execute();

// Rename a index (as a convenience for the ALTER INDEX statement)
create.alterTable("table").renameIndex("old_index").to("new_index").execute();
 

4.4.1.5. ALTER VIEW

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ALTER VIEW statement allows of altering existing views. It supports the following subclauses:

 

4.4.1.5.1. ALTER VIEW .. RENAME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement allows for renaming a view.

Dialect support

This example using jOOQ:

alterView("v").renameTo("new_name")

Translates to the following dialect specific expressions:

-- ASE, SQLSERVER
EXEC sp_rename v, new_name

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, POSTGRES, SNOWFLAKE, TRINO, VERTICA
ALTER VIEW  v RENAME TO new_name

-- EXASOL, TERADATA
RENAME VIEW v TO new_name

-- HSQLDB, YUGABYTEDB
ALTER TABLE  v RENAME TO new_name

-- ORACLE
RENAME v TO new_name

-- ACCESS, AURORA_MYSQL, BIGQUERY, DB2, DERBY, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SYBASE
/* UNSUPPORTED */
 

4.4.1.5.2. ALTER VIEW IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS clause:

Dialect support

This example using jOOQ:

alterViewIfExists("v").renameTo("new_name")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, POSTGRES
ALTER VIEW  IF EXISTS v RENAME TO new_name

-- ORACLE
BEGIN
  EXECUTE IMMEDIATE '
    RENAME v TO new_name
  ';
EXCEPTION
  WHEN others THEN
    IF sqlerrm LIKE 'ORA-00942%' THEN NULL;
    ELSIF sqlerrm LIKE 'ORA-04043%' THEN NULL;
    ELSE RAISE;
    END IF;
END;

-- SNOWFLAKE
ALTER VIEW  v RENAME TO new_name

-- SQLSERVER
BEGIN TRY
  EXEC sp_rename v, new_name
END TRY
BEGIN CATCH
  IF error_number() != 15225 THROW;
END CATCH

-- YUGABYTEDB
ALTER TABLE  IF EXISTS v RENAME TO new_name

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, 
-- REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.4.2. The CREATE statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CREATE statement is the most important DDL statement. It allows for creating new objects in the database catalog.

 

4.4.2.1. CREATE INDEX

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CREATE INDEX statement allows for creating indexes on table columns.

CREATE INDEX

In its simplest form, the statement can be used like this:

// Create an index on a single column
create.createIndex("index").on("table", "column").execute();

// Create an index on several columns
create.createIndex("index").on("table", "column1", "column2").execute();

CREATE UNIQUE INDEX

In many dialects, there is a possibility of creating a unique index, which acts like a constraint (see ALTER TABLE or CREATE TABLE), but is not really a constraint. Most dialects will create an index automatically to enforce a UNIQUE constraint, so using a constraint instead may seem a bit cleaner. A UNIQUE INDEX is created like this:

// Create an index on a single column
create.createUniqueIndex("index").on("table", "column").execute();

// Create an index on several columns
create.createUniqueIndex("index").on("table", "column1", "column2").execute();

Sorted indexes

In most dialects, indexes have their columns sorted ascendingly by default. If you wish to create an index with a differing sort order, you can do so by providing the order explicitly:

// Create a sorted index on several columns
create.createIndex("index").on(
  table(name("table")),
  field(name("column1")).asc(),
  field(name("column2")).desc()
).execute();

Partial indexes (with WHERE clause)

A few dialects support a WHERE clause when creating an index. This is very useful to drastically reduce the size of an index, and thus index maintenance, if only parts of the data of a column need to be included in the index.

// Create a partial index
create.createIndex("index").on("table", "column").where(field(name("column")).gt(0)).execute();
 

4.4.2.2. CREATE SCHEMA

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CREATE SCHEMA statement is used to create a new schema in the database catalog.

// Create a schema
create.createSchema("new_schema").execute();

Dialect support

This example using jOOQ:

createSchema("s")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB
CREATE SCHEMA s

-- ORACLE
CREATE USER s NO AUTHENTICATION QUOTA UNLIMITED ON USERS

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.4.2.3. CREATE SEQUENCE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CREATE SEQUENCE statement is used to create a new sequence in the database catalog.

// Create a sequence with default flags
create.createSequence("sequence").execute();
 

4.4.2.4. CREATE TABLE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Arguably the most used DDL statement is the CREATE TABLE statement.

The following subsections discuss various usages of CREATE TABLE, as well as the relevant bits of meta data that can be added to a table.

 

4.4.2.4.1. Columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

All tables contain at least one column (except for some esoteric cases in PostgreSQL), and all SQL dialects support creating such tables:

// Create a new table with a column
create.createTable("table")
      .column("col1", INTEGER)
      .execute();

Dialect support

This example using jOOQ:

createTable("table").column("col1", INTEGER)

Translates to the following dialect specific expressions:

-- ACCESS, DB2, FIREBIRD, HANA, INFORMIX, TERADATA
CREATE TABLE table (
  col1 integer
)

-- ASE, SYBASE
CREATE TABLE table (
  col1 int NULL
)

-- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, TRINO, VERTICA, YUGABYTEDB
CREATE TABLE table (
  col1 int
)

-- BIGQUERY
CREATE TABLE table (
  col1 int64
)

-- COCKROACHDB
CREATE TABLE table (
  col1 int4
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  col1 number(10)
)

-- SQLITE
CREATE TABLE "table" (
  col1 int
)
 

4.4.2.4.2. Nullability

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Nullability is a property of a data type, and as such can be attached to the data type using various methods. The default nullability is RDBMS specific, so if you want to be vendor agnostic about nullability in your DDL, better always state it explicitly, for example:

// Specify nullability on columns
create.createTable("table")
      .column("vendor_specific_default", INTEGER)
      .column("explicit_nullable", INTEGER.nullable(false))
      .column("explicit_not_nullable", INTEGER.nullable(true))
      .execute();

Dialect support

This example using jOOQ:

createTable("table")
      .column("vendor_specific_default", INTEGER)
      .column("explicit_nullable", INTEGER.nullable(false))
      .column("explicit_not_nullable", INTEGER.nullable(true))

Translates to the following dialect specific expressions:

-- ACCESS, DB2, HANA, INFORMIX, TERADATA
CREATE TABLE table (
  vendor_specific_default integer,
  explicit_nullable integer NOT NULL,
  explicit_not_nullable integer NULL
)

-- ASE, SYBASE
CREATE TABLE table (
  vendor_specific_default int NULL,
  explicit_nullable int NOT NULL,
  explicit_not_nullable int NULL
)

-- AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, EXASOL, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLSERVER, 
-- VERTICA, YUGABYTEDB
CREATE TABLE table (
  vendor_specific_default int,
  explicit_nullable int NOT NULL,
  explicit_not_nullable int NULL
)

-- BIGQUERY
CREATE TABLE table (
  vendor_specific_default int64,
  explicit_nullable int64 NOT NULL,
  explicit_not_nullable int64
)

-- COCKROACHDB
CREATE TABLE table (
  vendor_specific_default int4,
  explicit_nullable int4 NOT NULL,
  explicit_not_nullable int4 NULL
)

-- DERBY, H2, HSQLDB
CREATE TABLE table (
  vendor_specific_default int,
  explicit_nullable int NOT NULL,
  explicit_not_nullable int
)

-- FIREBIRD
CREATE TABLE table (
  vendor_specific_default integer,
  explicit_nullable integer NOT NULL,
  explicit_not_nullable integer
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  vendor_specific_default number(10),
  explicit_nullable number(10) NOT NULL,
  explicit_not_nullable number(10) NULL
)

-- SQLITE
CREATE TABLE "table" (
  vendor_specific_default int,
  explicit_nullable int NOT NULL,
  explicit_not_nullable int NULL
)

-- TRINO
CREATE TABLE table (
  vendor_specific_default int,
  explicit_nullable int,
  explicit_not_nullable int
)
 

4.4.2.4.3. Defaults

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DEFAULT expression on a column definition defines what value the column should contain if it is omitted in an INSERT statement, or if an explicit DEFAULT expression is used in INSERT or UPDATE. By default, this is NULL in most dialects

// Create a new table with a column with a default expression
create.createTable("table")
      .column("column1", INTEGER.defaultValue(1))
      .execute();

To trigger this DEFAULT expression, you can run this, for example:

// Insert a row using the default expression
create.insertInto(table(name("table"))).defaultValues().execute();

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER.defaultValue(1))

Translates to the following dialect specific expressions:

-- ACCESS, DB2, FIREBIRD, HANA, INFORMIX, TERADATA
CREATE TABLE table (
  column1 integer DEFAULT 1
)

-- ASE
CREATE TABLE table (
  column1 int DEFAULT 1 NULL
)

-- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB
CREATE TABLE table (
  column1 int DEFAULT 1
)

-- BIGQUERY
CREATE TABLE table (
  column1 int64 DEFAULT 1
)

-- COCKROACHDB
CREATE TABLE table (
  column1 int4 DEFAULT 1
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  column1 number(10) DEFAULT 1
)

-- SQLITE
CREATE TABLE "table" (
  column1 int DEFAULT 1
)

-- SYBASE
CREATE TABLE table (
  column1 int NULL DEFAULT 1
)

-- TRINO
/* UNSUPPORTED */
 

4.4.2.4.4. Identities

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

An IDENTITY is a special type of DEFAULT on a column, which is computed only on INSERT, and should usually not be replaced by user content. It computes a new value for a surrogate key. Most dialects default to using some system sequence based IDENTITY, though a UUID or some other unique value might work as well.

In jOOQ, it is currently only possible to specify whether a column is an IDENTITY at all, not to influence the value generation algorithm.

// Create a new table with a column with a default expression
create.createTable("table")
      .column("column1", INTEGER.identity(true))
      .execute();

Whether an IDENTITY also needs to be explicitly NOT NULL or a PRIMARY KEY is vendor specific. Ideally, both of these properties are set as well on identities.

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER.identity(true))

Translates to the following dialect specific expressions:

-- ACCESS
CREATE TABLE table (
  column1 AUTOINCREMENT NOT NULL
)

-- ASE, EXASOL
CREATE TABLE table (
  column1 int IDENTITY NOT NULL
)

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
CREATE TABLE table (
  column1 int NOT NULL AUTO_INCREMENT
)

-- AURORA_POSTGRES
CREATE TABLE table (
  column1 SERIAL4 NOT NULL
)

-- COCKROACHDB
CREATE TABLE table (
  column1 integer DEFAULT (unique_rowid() % 2 ^ 31) NOT NULL
)

-- DB2, FIREBIRD
CREATE TABLE table (
  column1 integer GENERATED BY DEFAULT AS IDENTITY NOT NULL
)

-- DERBY, POSTGRES, YUGABYTEDB
CREATE TABLE table (
  column1 int GENERATED BY DEFAULT AS IDENTITY NOT NULL
)

-- H2
CREATE TABLE table (
  column1 int NOT NULL GENERATED BY DEFAULT AS IDENTITY
)

-- HANA, TERADATA
CREATE TABLE table (
  column1 integer NOT NULL GENERATED BY DEFAULT AS IDENTITY
)

-- HSQLDB
CREATE TABLE table (
  column1 int GENERATED BY DEFAULT AS IDENTITY(START WITH 1) NOT NULL
)

-- INFORMIX
CREATE TABLE table (
  column1 SERIAL NOT NULL
)

-- ORACLE
CREATE TABLE table (
  column1 number(10) GENERATED BY DEFAULT AS IDENTITY(START WITH 1) NOT NULL
)

-- REDSHIFT, SQLDATAWAREHOUSE, SQLSERVER
CREATE TABLE table (
  column1 int IDENTITY(1, 1) NOT NULL
)

-- SNOWFLAKE
CREATE TABLE table (
  column1 number(10) IDENTITY NOT NULL
)

-- SQLITE
CREATE TABLE "table" (
  column1 integer PRIMARY KEY AUTOINCREMENT NOT NULL
)

-- SYBASE
CREATE TABLE table (
  column1 int NOT NULL IDENTITY
)

-- VERTICA
CREATE TABLE table (
  column1 IDENTITY(1, 1) NOT NULL
)

-- BIGQUERY, DUCKDB, TRINO
/* UNSUPPORTED */
 

4.4.2.4.5. Primary key

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In a normalised database, all tables should have a PRIMARY KEY. In jOOQ, numerous features are enabled by tables that have one, including for example UpdatableRecords. To create a table with a primary key, write any of these:

// Create a new table with columns and unnamed constraints
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          primaryKey("column1")
      )
      .execute();

// Create a new table with columns and named constraints (recommended if you want to alter the constraint)
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("pk").primaryKey("column1")
      )
      .execute();

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("pk").primaryKey("column1")
      )

Translates to the following dialect specific expressions:

-- ACCESS, FIREBIRD, HANA
CREATE TABLE table (
  column1 integer,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- ASE, SYBASE
CREATE TABLE table (
  column1 int NULL,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, POSTGRES, REDSHIFT, YUGABYTEDB
CREATE TABLE table (
  column1 int,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- BIGQUERY
CREATE TABLE table (
  column1 int64
)

-- COCKROACHDB
CREATE TABLE table (
  column1 int4,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- DB2, TERADATA
CREATE TABLE table (
  column1 integer NOT NULL,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- INFORMIX
CREATE TABLE table (
  column1 integer,
  PRIMARY KEY (column1) CONSTRAINT pk
)

-- MARIADB, MEMSQL, MYSQL, SQLSERVER
CREATE TABLE table (
  column1 int NOT NULL,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  column1 number(10),
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- SQLDATAWAREHOUSE
CREATE TABLE table (
  column1 int,
  CONSTRAINT pk PRIMARY KEY NONCLUSTERED (column1) NOT ENFORCED
)

-- SQLITE
CREATE TABLE "table" (
  column1 int,
  CONSTRAINT pk PRIMARY KEY (column1)
)

-- TRINO
CREATE TABLE table (
  column1 int
)

-- VERTICA
CREATE TABLE table (
  column1 int,
  dummy int,
  CONSTRAINT pk PRIMARY KEY (column1)
)
 

4.4.2.4.6. Unique constraints

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A candidate key that is not ideal for a Primary key should still be declared UNIQUE to enforce uniqueness, as well as for query performance reasons. In jOOQ, this can be done with the following approaches:

// Create a new table with columns and unnamed constraints
create.createTable("table")
      .column("column1", INTEGER)
      .column("column2", INTEGER)
      .column("column3", INTEGER)
      .constraints(
          unique("column1"),
          unique("column2", "column3")
      )
      .execute();

// Create a new table with columns and named constraints (recommended if you want to alter the constraint)
create.createTable("table")
      .column("column1", INTEGER)
      .column("column2", INTEGER)
      .column("column3", INTEGER)
      .constraints(
          constraint("uk1").unique("column1"),
          constraint("uk2").unique("column2", "column3")
      )
      .execute();

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("uk").unique("column1")
      )

Translates to the following dialect specific expressions:

-- ACCESS, DB2, FIREBIRD, HANA, TERADATA
CREATE TABLE table (
  column1 integer,
  CONSTRAINT uk UNIQUE (column1)
)

-- ASE, SYBASE
CREATE TABLE table (
  column1 int NULL,
  CONSTRAINT uk UNIQUE (column1)
)

-- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLSERVER, VERTICA, YUGABYTEDB
CREATE TABLE table (
  column1 int,
  CONSTRAINT uk UNIQUE (column1)
)

-- BIGQUERY
CREATE TABLE table (
  column1 int64
)

-- COCKROACHDB
CREATE TABLE table (
  column1 int4,
  CONSTRAINT uk UNIQUE (column1)
)

-- INFORMIX
CREATE TABLE table (
  column1 integer,
  UNIQUE (column1) CONSTRAINT uk
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  column1 number(10),
  CONSTRAINT uk UNIQUE (column1)
)

-- SQLDATAWAREHOUSE
CREATE TABLE table (
  column1 int,
  CONSTRAINT uk UNIQUE (column1) NOT ENFORCED
)

-- SQLITE
CREATE TABLE "table" (
  column1 int,
  CONSTRAINT uk UNIQUE (column1)
)

-- TRINO
CREATE TABLE table (
  column1 int
)
 

4.4.2.4.7. Foreign keys

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A foreign key is a tool that helps further normalise your database by guaranteeing that a referenced value exists in a parent table. In our sample database, it enforces the integrity of the BOOK.AUTHOR_ID reference. Besides integrity, it can be a very useful tool for optimising more sophisticated execution plans, e.g. to support JOIN elimination. In jOOQ, create foreign keys like this:

// Create a new table with columns and unnamed constraints
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          foreignKey("column1").references("other_table", "other_column1")
      )
      .execute();

// Create a new table with columns and named constraints (recommended if you want to alter the constraint)
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("fk").foreignKey("column1").references("other_table", "other_column1")
      )
      .execute();

jOOQ's code generator will pick up foreign keys for a variety of purposes, including navigational methods, the ON KEY joins.

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("fk").foreignKey("column1").references("other_table", "other_column1")
      )

Translates to the following dialect specific expressions:

-- ACCESS, DB2, FIREBIRD, HANA, TERADATA
CREATE TABLE table (
  column1 integer,
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- ASE, SYBASE
CREATE TABLE table (
  column1 int NULL,
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB
CREATE TABLE table (
  column1 int,
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- BIGQUERY
CREATE TABLE table (
  column1 int64
)

-- COCKROACHDB
CREATE TABLE table (
  column1 int4,
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- INFORMIX
CREATE TABLE table (
  column1 integer,
  FOREIGN KEY (column1) REFERENCES other_table (other_column1) CONSTRAINT fk
)

-- ORACLE, SNOWFLAKE
CREATE TABLE table (
  column1 number(10),
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- SQLITE
CREATE TABLE "table" (
  column1 int,
  CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1)
)

-- TRINO
CREATE TABLE table (
  column1 int
)
 

4.4.2.4.8. Check constraints

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A CHECK constraint is a simple, yet very effective means of enforcing data integrity on a row basis. Want to ensure a number is only ever positive? Use a CHECK constraint.

// Create a new table with columns and unnamed constraints
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          check(field(name("column1"), INTEGER).gt(0))
      )
      .execute();

// Create a new table with columns and named constraints (recommended if you want to alter the constraint)
create.createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("chk").check(field(name("column1"), INTEGER).gt(0))
      )
      .execute();

Just like the previous constraints, this one can be used by the optimiser to remove some redundant predicates, see e.g. this blog post.

Dialect support

This example using jOOQ:

createTable("table")
      .column("column1", INTEGER)
      .constraints(
          constraint("chk").check(field(name("column1"), INTEGER).gt(0))
      )

Translates to the following dialect specific expressions:

-- ACCESS, DB2, FIREBIRD, HANA, TERADATA
CREATE TABLE table (
  column1 integer,
  CONSTRAINT chk CHECK (column1 > 0)
)

-- ASE, SYBASE
CREATE TABLE table (
  column1 int NULL,
  CONSTRAINT chk CHECK (column1 > 0)
)

-- AURORA_POSTGRES, DERBY, H2, HSQLDB, MARIADB, MYSQL, POSTGRES, SQLSERVER, VERTICA, YUGABYTEDB
CREATE TABLE table (
  column1 int,
  CONSTRAINT chk CHECK (column1 > 0)
)

-- COCKROACHDB
CREATE TABLE table (
  column1 int4,
  CONSTRAINT chk CHECK (column1 > 0)
)

-- INFORMIX
CREATE TABLE table (
  column1 integer,
  CHECK (column1 > 0) CONSTRAINT chk
)

-- ORACLE
CREATE TABLE table (
  column1 number(10),
  CONSTRAINT chk CHECK (column1 > 0)
)

-- SQLITE
CREATE TABLE "table" (
  column1 int,
  CONSTRAINT chk CHECK (column1 > 0)
)

-- AURORA_MYSQL, BIGQUERY, DUCKDB, EXASOL, MEMSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, TRINO
/* UNSUPPORTED */
 

4.4.2.4.9. From a SELECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Occasionally, creating a table from a SELECT statement is very useful, copying the source table's data types and data.

// Create a new table from a source SELECT statement
create.createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))
      .execute();

Dialect support

This example using jOOQ:

createTable("book_archive")
      .as(select(BOOK.ID, BOOK.TITLE).from(BOOK))

Translates to the following dialect specific expressions:

-- ACCESS, ASE, SQLDATAWAREHOUSE, SQLSERVER
SELECT BOOK.ID, BOOK.TITLE
INTO book_archive
FROM BOOK

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, 
-- REDSHIFT, SNOWFLAKE, SQLITE, VERTICA, YUGABYTEDB
CREATE TABLE book_archive
AS
SELECT BOOK.ID, BOOK.TITLE
FROM BOOK

-- DB2
BEGIN
  EXECUTE IMMEDIATE '
    CREATE TABLE book_archive
    AS (
      SELECT BOOK.ID, BOOK.TITLE
      FROM BOOK
    ) WITH NO DATA
  ';
  EXECUTE IMMEDIATE '
    INSERT INTO book_archive
    SELECT BOOK.ID, BOOK.TITLE
    FROM BOOK
  ';
END

-- HANA
CREATE TABLE book_archive
AS (
  SELECT BOOK.ID, BOOK.TITLE
  FROM BOOK
)

-- HSQLDB, TERADATA
CREATE TABLE book_archive
AS (
  SELECT BOOK.ID, BOOK.TITLE
  FROM BOOK
)
WITH DATA

-- BIGQUERY, FIREBIRD, INFORMIX, SYBASE, TRINO
/* UNSUPPORTED */
 

4.4.2.4.10. Temporary tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Many dialects support different notions of "temporary" tables, i.e. tables whose data and/or meta data is stored only temporarily. The details of these temporary are implementation specific. jOOQ supports the following syntaxes, both with explicit column lists or as CREATE TABLE AS SELECT:

// Create a new temporary table
create.createTemporaryTable("book_archive")
      .column("column1", INTEGER)
      .execute();

// Create a new temporary table
create.createGlobalTemporaryTable("book_archive")
      .column("column1", INTEGER)
      .execute();

Dialect support

This example using jOOQ:

createTemporaryTable("book_archive")
      .column("column1", INTEGER)

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, YUGABYTEDB
CREATE TEMPORARY TABLE book_archive (
  column1 int
)

-- COCKROACHDB
CREATE GLOBAL TEMPORARY TABLE book_archive (
  column1 int4
)

-- FIREBIRD, HANA, TERADATA
CREATE GLOBAL TEMPORARY TABLE book_archive (
  column1 integer
)

-- ORACLE, SNOWFLAKE
CREATE GLOBAL TEMPORARY TABLE book_archive (
  column1 number(10)
)

-- VERTICA
CREATE GLOBAL TEMPORARY TABLE book_archive (
  column1 int
)

-- ACCESS, ASE, BIGQUERY, DB2, DERBY, EXASOL, H2, HSQLDB, INFORMIX, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TRINO
/* UNSUPPORTED */
 

4.4.2.5. CREATE VIEW

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement allows for creating a VIEW in the database catalog:

// Create a new view
create.createView("books_and_authors", "author_id", "first_name", "last_name", "book_id", "title")
      .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.ID, BOOK.TITLE)
          .from(AUTHOR)
          .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)))
      .execute();

Dialect support

This example using jOOQ:

createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR))

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, 
-- HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, VERTICA, YUGABYTEDB
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR

-- MEMSQL
CREATE VIEW a
AS
SELECT t.id
FROM (
  SELECT AUTHOR.ID id
  FROM AUTHOR
) t

-- TRINO
CREATE VIEW a
AS
SELECT t.id
FROM (
  SELECT AUTHOR.ID
  FROM AUTHOR
) t (id)
 

4.4.2.5.1. WITH CHECK OPTION

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A CREATE VIEW statement of an updatable view can have a WITH CHECK OPTION clause appended to it, to make sure that any INSERT or UPDATE statement will produce rows that are also visible through this view.

// Create a new view
create.createView("early_authors", "author_id", "first_name", "last_name")
      .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
          .from(AUTHOR)

          // Any inserted or updated authors must continue to satisfy this condition
          .where(AUTHOR.ID.lt(200))

          // The flag is set on the Select object, not the view
          .withCheckOption())
      .execute();
The flag is set on the SELECT object, not the CREATE VIEW statement, as it is also made available to inline views.

Dialect support

This example using jOOQ:

createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR).withCheckOption())

Translates to the following dialect specific expressions:

-- ASE, DB2, FIREBIRD, HANA, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLSERVER, SYBASE, TERADATA
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
WITH CHECK OPTION

-- ACCESS, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MEMSQL, REDSHIFT, 
-- SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, TRINO, VERTICA, YUGABYTEDB
/* UNSUPPORTED */
 

4.4.2.5.2. WITH READ ONLY

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A CREATE VIEW statement of an updatable view can have a WITH READ ONLY clause appended to it, to make sure that it cannot be updated.

// Create a new view
create.createView("authors", "author_id", "first_name", "last_name")
      .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
          .from(AUTHOR)
          .withReadOnly())
      .execute();
The flag is set on the SELECT object, not the CREATE VIEW statement, as it is also made available to inline views.

Dialect support

This example using jOOQ:

createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR).withReadOnly())

Translates to the following dialect specific expressions:

-- ACCESS
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM (
  SELECT count(*) dual
  FROM MSysResources
) AS dual
WHERE 1 = 0

-- ASE, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, VERTICA
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
WHERE 1 = 0

-- AURORA_MYSQL
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM DUAL
WHERE 1 = 0

-- AURORA_POSTGRES, COCKROACHDB, H2, MARIADB, MYSQL, POSTGRES, SNOWFLAKE, YUGABYTEDB
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
WHERE FALSE

-- BIGQUERY
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION DISTINCT
SELECT NULL
FROM UNNEST([STRUCT(1 AS dual)]) AS dual
WHERE FALSE

-- DB2
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM SYSIBM.DUAL
WHERE 1 = 0

-- DERBY
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT CAST(NULL AS int)
FROM SYSIBM.SYSDUMMY1
WHERE FALSE

-- EXASOL
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM DUAL
WHERE FALSE

-- FIREBIRD
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM RDB$DATABASE
WHERE 1 = 0

-- HANA, ORACLE
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
WITH READ ONLY

-- HSQLDB
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM (VALUES(1)) AS dual(dual)
WHERE FALSE

-- INFORMIX
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM (
  SELECT 1 AS dual
  FROM systables
  WHERE (tabid = 1)
) AS dual
WHERE 1 = 0

-- MEMSQL
CREATE VIEW a
AS
SELECT t.id
FROM (
  SELECT 
    t.*
  FROM (
    SELECT AUTHOR.ID id
    FROM AUTHOR
    UNION
    SELECT NULL
    FROM DUAL
    WHERE 1 = 0
  ) t
) t

-- SYBASE
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM SYS.DUMMY
WHERE 1 = 0

-- TERADATA
CREATE VIEW a(id)
AS
SELECT AUTHOR.ID
FROM AUTHOR
UNION
SELECT NULL
FROM (
  SELECT 1 AS "dual"
) AS "dual"
WHERE 1 = 0

-- DUCKDB, TRINO
/* UNSUPPORTED */
 

4.4.3. The DROP statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DROP statement is used to drop objects from the database catalog.

 

4.4.3.1. DROP INDEX

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement is used to drop an INDEX from the database catalog.

// Drop an index (for indexes stored in the schema namespace, i.e. most dialects)
create.dropIndex("index").execute();

// Drop an index (for indexes stored in the table namespace, e.g. MySQL, SQL Server)
create.dropIndex("index").on("table").execute();

CASCADE

It is possible to supply a CASCADE or RESTRICT clause, explicitly

// Specify the CASCADE / RESTRICT clauses explicitly
create.dropIndex("index").cascade().execute();
create.dropIndex("index").restrict().execute();

Dialect support

This example using jOOQ:

dropIndex("i")

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, YUGABYTEDB
DROP INDEX i

-- BIGQUERY, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, VERTICA
/* UNSUPPORTED */
 

4.4.3.1.1. IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For idempotent execution of DDL scripts, the useful IF EXISTS clause is supported by jOOQ.

// Drop an index
create.dropIndexIfExists("index").execute();

Dialect support

This example using jOOQ:

dropIndexIfExists("index")

Translates to the following dialect specific expressions:

-- ACCESS
DROP INDEX index

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SYBASE, YUGABYTEDB
DROP INDEX IF EXISTS index

-- DB2
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END;
  EXECUTE IMMEDIATE '
    DROP INDEX index
  ';
END

-- FIREBIRD
EXECUTE BLOCK
AS
BEGIN
  EXECUTE STATEMENT '
    DROP INDEX index
  ';
  WHEN sqlcode -607 DO
    BEGIN END
END

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 261 BEGIN END;
  EXECUTE IMMEDIATE '
    DROP INDEX index
  ';
END;

-- MYSQL

CREATE PROCEDURE block_1702641451036_2199457()
MODIFIES SQL DATA
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42000' BEGIN END;
  DROP INDEX index;
END;
CALL block_1702641451036_2199457();
DROP PROCEDURE block_1702641451036_2199457;

-- SQLDATAWAREHOUSE
BEGIN TRY
  DROP INDEX index
END TRY
BEGIN CATCH
  IF error_number() != 3701 BEGIN
    DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE();
    DECLARE @ErrorSeverity INT = ERROR_SEVERITY();
    DECLARE @ErrorState INT = ERROR_STATE();
    RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState);
  END;
END CATCH

-- SQLITE
DROP INDEX IF EXISTS "index"

-- SQLSERVER
BEGIN TRY
  DROP INDEX index
END TRY
BEGIN CATCH
  IF error_number() != 3701 THROW;
END CATCH

-- ASE, AURORA_MYSQL, BIGQUERY, DERBY, EXASOL, MEMSQL, REDSHIFT, SNOWFLAKE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.4.3.2. DROP SCHEMA

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement is used to drop an SCHEMA from the database catalog.

// Drop a schema
create.dropSchema("schema").execute();

CASCADE

It is possible to supply a CASCADE or RESTRICT clause, explicitly

// Specify the CASCADE / RESTRICT clauses explicitly
create.dropSchema("schema").cascade().execute();
create.dropSchema("schema").restrict().execute();

Dialect support

This example using jOOQ:

dropSchema("s")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB
DROP SCHEMA s

-- DB2, DERBY
DROP SCHEMA s RESTRICT

-- ORACLE
DROP USER s

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.4.3.2.1. IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For idempotent execution of DDL scripts, the useful IF EXISTS clause is supported by jOOQ.

// Drop a schema
create.dropSchemaIfExists("schema").execute();

Dialect support

This example using jOOQ:

dropSchemaIfExists("schema")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, 
-- VERTICA, YUGABYTEDB
DROP SCHEMA IF EXISTS schema

-- DB2
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END;
  EXECUTE IMMEDIATE '
    DROP SCHEMA schema RESTRICT
  ';
END

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 362 BEGIN END;
  EXECUTE IMMEDIATE '
    DROP SCHEMA schema
  ';
END;

-- ORACLE
DROP USER IF EXISTS schema

-- SQLDATAWAREHOUSE
BEGIN TRY
  DROP SCHEMA schema
END TRY
BEGIN CATCH
  IF error_number() != 15151 BEGIN
    DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE();
    DECLARE @ErrorSeverity INT = ERROR_SEVERITY();
    DECLARE @ErrorState INT = ERROR_STATE();
    RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState);
  END;
END CATCH

-- SQLSERVER
BEGIN TRY
  DROP SCHEMA schema
END TRY
BEGIN CATCH
  IF error_number() != 15151 THROW;
END CATCH

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.4.3.3. DROP SEQUENCE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement is used to drop an SEQUENCE from the database catalog.

// Drop a sequence
create.dropSequence("sequence").execute();

Dialect support

This example using jOOQ:

dropSequence("s")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SNOWFLAKE, 
-- SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
DROP SEQUENCE s

-- DERBY
DROP SEQUENCE s RESTRICT

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DUCKDB, EXASOL, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, TERADATA, 
-- TRINO
/* UNSUPPORTED */
 

4.4.3.3.1. IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For idempotent execution of DDL scripts, the useful IF EXISTS clause is supported by jOOQ.

// Drop a sequence
create.dropSequenceIfExists("sequence").execute();

Dialect support

This example using jOOQ:

dropSequenceIfExists("sequence")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SNOWFLAKE, VERTICA, YUGABYTEDB
DROP SEQUENCE IF EXISTS sequence

-- DB2
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END;
  EXECUTE IMMEDIATE '
    DROP SEQUENCE sequence
  ';
END

-- FIREBIRD
EXECUTE BLOCK
AS
BEGIN
  EXECUTE STATEMENT '
    DROP SEQUENCE sequence
  ';
  WHEN sqlcode -607 DO
    BEGIN END
END

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 313 BEGIN END;
  EXECUTE IMMEDIATE '
    DROP SEQUENCE sequence
  ';
END;

-- SQLSERVER
BEGIN TRY
  DROP SEQUENCE sequence
END TRY
BEGIN CATCH
  IF error_number() != 3701 THROW;
END CATCH

-- SYBASE
BEGIN
  DROP SEQUENCE sequence;
EXCEPTION
  WHEN others THEN
END;BEGIN
DROP SEQUENCE sequence
';
WHEN sqlcode -607 DO
BEGIN END
END;

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, 
-- TERADATA, TRINO
/* UNSUPPORTED */
 

4.4.3.4. DROP TABLE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement is used to drop an TABLE from the database catalog.

// Drop a table
create.dropTable("table").execute();

CASCADE

It is possible to supply a CASCADE or RESTRICT clause, explicitly

// Specify the CASCADE / RESTRICT clauses explicitly
create.dropTable("table").cascade().execute();
create.dropTable("table").restrict().execute();

Dialect support

This example using jOOQ:

dropTable("t")

Translates to the following dialect specific expressions:

-- All dialects
DROP TABLE t
 

4.4.3.4.1. IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For idempotent execution of DDL scripts, the useful IF EXISTS clause is supported by jOOQ.

// Drop a table
create.dropTableIfExists("table").execute();

Dialect support

This example using jOOQ:

dropTableIfExists("table")

Translates to the following dialect specific expressions:

-- ACCESS
DROP TABLE table

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- POSTGRES, SNOWFLAKE, SYBASE, VERTICA, YUGABYTEDB
DROP TABLE IF EXISTS table

-- DB2
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END;
  EXECUTE IMMEDIATE '
    DROP TABLE table
  ';
END

-- FIREBIRD
EXECUTE BLOCK
AS
BEGIN
  EXECUTE STATEMENT '
    DROP TABLE table
  ';
  WHEN sqlcode -607 DO
    BEGIN END
END

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 259 BEGIN END;
  EXECUTE IMMEDIATE '
    DROP TABLE table
  ';
END;

-- SQLDATAWAREHOUSE
BEGIN TRY
  DROP TABLE table
END TRY
BEGIN CATCH
  IF error_number() != 3701 BEGIN
    DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE();
    DECLARE @ErrorSeverity INT = ERROR_SEVERITY();
    DECLARE @ErrorState INT = ERROR_STATE();
    RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState);
  END;
END CATCH

-- SQLITE
DROP TABLE IF EXISTS "table"

-- SQLSERVER
BEGIN TRY
  DROP TABLE table
END TRY
BEGIN CATCH
  IF error_number() != 3701 THROW;
END CATCH

-- ASE, BIGQUERY, DERBY, REDSHIFT, TERADATA, TRINO
/* UNSUPPORTED */
 

4.4.3.5. DROP VIEW

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

This statement is used to drop an VIEW from the database catalog.

// Drop a view
create.dropView("view").execute();

Dialect support

This example using jOOQ:

dropView("v")

Translates to the following dialect specific expressions:

-- All dialects
DROP VIEW v
 

4.4.3.5.1. IF EXISTS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

For idempotent execution of DDL scripts, the useful IF EXISTS clause is supported by jOOQ.

// Drop a view
create.dropViewIfExists("view").execute();

Dialect support

This example using jOOQ:

dropViewIfExists("v")

Translates to the following dialect specific expressions:

-- ACCESS
DROP VIEW v

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, 
-- ORACLE, POSTGRES, SQLITE, SYBASE, TRINO, VERTICA, YUGABYTEDB
DROP VIEW IF EXISTS v

-- DB2
BEGIN
  DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END;
  EXECUTE IMMEDIATE '
    DROP VIEW v
  ';
END

-- FIREBIRD
EXECUTE BLOCK
AS
BEGIN
  EXECUTE STATEMENT '
    DROP VIEW v
  ';
  WHEN sqlcode -607 DO
    BEGIN END
END

-- HANA
DO BEGIN
  DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 321 BEGIN END;
  EXECUTE IMMEDIATE '
    DROP VIEW v
  ';
END;

-- SQLDATAWAREHOUSE
BEGIN TRY
  DROP VIEW v
END TRY
BEGIN CATCH
  IF error_number() != 3701 BEGIN
    DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE();
    DECLARE @ErrorSeverity INT = ERROR_SEVERITY();
    DECLARE @ErrorState INT = ERROR_STATE();
    RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState);
  END;
END CATCH

-- SQLSERVER
BEGIN TRY
  DROP VIEW v
END TRY
BEGIN CATCH
  IF error_number() != 3701 THROW;
END CATCH

-- ASE, DERBY, REDSHIFT, SNOWFLAKE, TERADATA
/* UNSUPPORTED */
 

4.4.4. The TRUNCATE statement

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Even if the TRUNCATE statement mainly modifies data, it is generally considered to be a DDL statement. It is popular in many databases when you want to bypass constraints for table truncation. Databases may behave differently, when a truncated table is referenced by other tables. For instance, they may fail if records from a truncated table are referenced, even with ON DELETE CASCADE clauses in place. Please, consider your database manual to learn more about its TRUNCATE implementation.

The TRUNCATE syntax is trivial:

create.truncate(AUTHOR).execute();

TRUNCATE is not supported by all dialects. jOOQ will execute a DELETE FROM AUTHOR statement instead, which is roughly equivalent.

Dialect support

This example using jOOQ:

truncate(AUTHOR)

Translates to the following dialect specific expressions:

-- ACCESS, FIREBIRD, SQLITE, TERADATA
DELETE FROM AUTHOR

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, 
-- MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO, VERTICA, YUGABYTEDB
TRUNCATE TABLE AUTHOR

-- DB2
TRUNCATE TABLE AUTHOR IMMEDIATE
 

4.4.5. Generating DDL from objects

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

When using jOOQ's code generator, a whole set of meta data is generated with the generated artefacts, such as schemas, tables, columns, data types, constraints, default values, etc.

This meta data can be used to generate DDL CREATE statements in any SQL dialect, in order to partially restore the original schema again on a new database instance. This is particularly useful, for instance, when working with an Oracle production database, and an H2 in-memory test database. The following code produces the DDL for a schema:

// SCHEMA is the generated schema that contains a reference to all generated tables
Queries ddl =
DSL.using(configuration)
   .ddl(SCHEMA);

for (Query query : ddl.queries()) {
    System.out.println(query);
}

When executing the above, you should see something like the following:

create table "PUBLIC"."AUTHOR"(
  "ID" int not null,
  "FIRST_NAME" varchar(50) null,
  "LAST_NAME" varchar(50) not null,
  ...
  constraint "PK_AUTHOR"
    primary key ("ID")
)
create table "PUBLIC"."BOOK"(
  "ID" int not null,
  "AUTHOR_ID" int not null,
  "TITLE" varchar(400) not null,
  ...
  constraint "PK_BOOK"
    primary key ("ID")
)
...
alter table "PUBLIC"."BOOK"
  add constraint "FK_BOOK_AUTHOR_ID"
    foreign key ("AUTHOR_ID")
    references "AUTHOR" ("ID")

Do note that these features only restore parts of the original schema. For instance, vendor-specific storage clauses that are not available to jOOQ's generated meta data cannot be reproduced this way.

 

4.5. Catalog and schema expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Most databases know some sort of namespace to group objects like tables, stored procedures, sequences and others into a common catalog or schema. jOOQ uses the types org.jooq.Catalog and org.jooq.Schema to model these groupings, following SQL standard naming.

The catalog

A catalog is a collection of schemas. In many databases, the catalog corresponds to the database, or the database instance. Most often, catalogs are completely independent and their tables cannot be joined or combined in any way in a single query. The exception here is SQL Server and Sybase ASE, which allow for fully referencing tables from multiple catalogs:

SELECT *
FROM [Catalog1].[Schema1].[Table1] AS [t1]
JOIN [Catalog2].[Schema2].[Table2] AS [t2] ON [t1].[ID] = [t2].[ID]

Some dialects, including MariaDB, MemSQL, MySQL, use catalogs (databases) and schemas as the same thing. jOOQ treats databases in those dialects as schemas instead.

By default, the Settings.renderCatalog flag is turned on. In case a database supports querying multiple catalogs, jOOQ will generate fully qualified object names, including catalog name. For more information about this setting, see the manual's section about settings

jOOQ's code generator generates subpackages for each catalog.

The schema

A schema is a collection of objects, such as tables. Most databases support some sort of schema (except for some embedded databases like Access, Firebird, SQLite). In most databases, the schema is an independent structural entity. In Oracle, the schema and the user / owner is mostly treated as the same thing. An example of a query that uses fully qualified tables including schema names is:

SELECT *
FROM "Schema1"."Table1" AS "t1"
JOIN "Schema2"."Table2" AS "t2" ON "t1"."ID" = "t2"."ID"

By default, the Settings.renderSettings flag is turned on. jOOQ will thus generate fully qualified object names, including the setting name. For more information about this setting, see the manual's section about settings

 

4.6. Table expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The following sections explain the various types of table expressions supported by jOOQ

 

4.6.1. Generated Tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Most of the times, when thinking about a table expression you're probably thinking about an actual table in your database schema. If you're using jOOQ's code generator, you will have all tables from your database schema available to you as type safe Java objects. You can then use these tables in SQL FROM clauses, JOIN clauses or in other SQL statements, just like any other table expression. An example is given here:

SELECT *
FROM AUTHOR -- Table expression AUTHOR
JOIN BOOK   -- Table expression BOOK
ON (AUTHOR.ID = BOOK.AUTHOR_ID)
 
create.select()
      .from(AUTHOR) // Table expression AUTHOR
      .join(BOOK)   // Table expression BOOK
      .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
      .fetch();

The above example shows how AUTHOR and BOOK tables are joined in a SELECT statement. It also shows how you can access table columns by dereferencing the relevant Java attributes of their tables.

See the manual's section about generated tables for more information about what is really generated by the code generator

 

4.6.2. Aliased Tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The following sections illustrate how to alias tables, their columns, and how to reference columns from aliased tables.

Regardless of how the aliased table is defined, the same aliased table instance is rendered differently depending on where it is placed in the jOOQ expression tree. See the manual's section about rendering declarations vs references for more details.
 

4.6.2.1. Aliased generated tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The strength of jOOQ's code generator becomes more obvious when you perform table aliasing and dereference fields from generated aliased tables. This can best be shown by example:

-- Select all books by authors born after 1920,
-- named "Paulo" from a catalogue:



SELECT *
  FROM author a
  JOIN book b ON a.id = b.author_id
 WHERE a.year_of_birth > 1920
   AND a.first_name = 'Paulo'
 ORDER BY b.title
 
// Declare your aliases before using them in SQL:
Author a = AUTHOR.as("a");
Book b = BOOK.as("b");

// Use aliased tables in your statement
create.select()
      .from(a)
      .join(b).on(a.ID.eq(b.AUTHOR_ID))
      .where(a.YEAR_OF_BIRTH.gt(1920)
      .and(a.FIRST_NAME.eq("Paulo")))
      .orderBy(b.TITLE)
      .fetch();

As you can see in the above example, calling as() on generated tables returns an object of the same type as the table. This means that the resulting object can be used to dereference fields from the aliased table. This is quite powerful in terms of having your Java compiler check the syntax of your SQL statements. If you remove a column from a table, dereferencing that column from that table alias will cause compilation errors.

 

4.6.2.2. Aliased table expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Only few types of table expressions can leverage code generation to provide the SQL syntax typesafety shown previously, where generated tables are used. All tables, however, allow for dereferencing their fields through Table::field methods:

// "Type-unsafe" aliased table:
Table<?> a = AUTHOR.as("a");

// Get fields from a:
Field<?> id = a.field("ID");
Field<?> firstName = a.field("FIRST_NAME");

The same is true for derived tables, including unnamed derived tables whose synthetic table name is generated by jOOQ:

Table<?> named = table(select(AUTHOR.ID).from(AUTHOR)).as("t");
Table<?> unnamed = table(select(AUTHOR.ID).from(AUTHOR));

Field<?> id = named.field("ID");   // Produces a t.ID reference
Field<?> id = unnamed.field("ID"); // Produces a <generated-alias>.ID reference

Note that if you know that the ID column is of the same type as the AUTHOR.ID column, you can use that again to dereference the column as is explained again in the section dereferencing table columns.

// Now with inferred Integer type
Field<Integer> id = named.field(AUTHOR.ID);   // Produces a t.ID reference
Field<Integer> id = unnamed.field(AUTHOR.ID); // Produces a <generated-alias>.ID reference
 

4.6.2.3. Derived column lists

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard specifies how a table can be renamed / aliased in one go along with its columns. It references the term "derived column list" for the following syntax:

SELECT t.a, t.b
FROM (
  SELECT 1, 2
) t(a, b)

This feature is useful in various use-cases where column names are not known in advance (but the table's degree is!). An example for this are unnested tables, or the VALUES() table constructor:

-- Unnested tables
SELECT t.a, t.b
FROM unnest(my_table_function()) t(a, b)

-- VALUES() constructor
SELECT t.a, t.b
FROM VALUES(1, 2),(3, 4) t(a, b)

Only few databases really support such a syntax, but fortunately, jOOQ can emulate it easily using UNION ALL and an empty dummy record specifying the new column names. The two statements are equivalent:

-- Using derived column lists
SELECT t.a, t.b
FROM (
  SELECT 1, 2
) t(a, b)

-- Using UNION ALL and a dummy record
SELECT t.a, t.b
FROM (
  SELECT null a, null b FROM DUAL WHERE 1 = 0
  UNION ALL
  SELECT 1, 2 FROM DUAL
) t

In jOOQ, you would simply specify a varargs list of column aliases as such:

// Unnested tables
create.select().from(unnest(myTableFunction()).as("t", "a", "b")).fetch();

// VALUES() constructor
create.select().from(values(
  row(1, 2),
  row(3, 4)
).as("t", "a", "b"))
.fetch();

Dialect support

This example using jOOQ:

selectFrom(values(row(1, 2)).as("t", "a", "b"))

Translates to the following dialect specific expressions:

-- ACCESS
SELECT t.a, t.b
FROM (
  SELECT
    1 a,
    2 b
  FROM (
    SELECT count(*) dual
    FROM MSysResources
  ) AS dual
) t

-- ASE, REDSHIFT, SQLDATAWAREHOUSE, VERTICA
SELECT t.a, t.b
FROM (
  SELECT 1, 2
) t (a, b)

-- AURORA_MYSQL, MEMSQL
SELECT t.a, t.b
FROM (
  SELECT
    1 a,
    2 b
  FROM DUAL
) t

-- AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HSQLDB, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, TRINO, 
-- YUGABYTEDB
SELECT t.a, t.b
FROM (
  VALUES (1, 2)
) t (a, b)

-- BIGQUERY
SELECT t.a, t.b
FROM (
  SELECT
    null a,
    null b
  FROM UNNEST([STRUCT(1 AS dual)]) AS dual
  WHERE FALSE
  UNION ALL
  SELECT *
  FROM UNNEST ([ STRUCT (1, 2)]) t
) t

-- FIREBIRD
SELECT t.a, t.b
FROM (
  SELECT 1, 2
  FROM RDB$DATABASE
) t (a, b)

-- HANA
SELECT t.a, t.b
FROM (
  SELECT
    1 a,
    2 b
  FROM SYS.DUMMY
) t

-- INFORMIX
SELECT t.a, t.b
FROM (
  TABLE (MULTISET { ROW (1, 2)})
) t (a, b)

-- MARIADB
SELECT t.a, t.b
FROM (
  SELECT
    1 a,
    2 b
) t

-- MYSQL
SELECT t.a, t.b
FROM (
  VALUES ROW (1, 2)
) t (a, b)

-- SQLITE
SELECT t.a, t.b
FROM (
  SELECT
    null a,
    null b
  WHERE 1 = 0
  UNION ALL
  SELECT *
  FROM (
    VALUES (1, 2)
  ) t
) t

-- SYBASE
SELECT t.a, t.b
FROM (
  SELECT 1, 2
  FROM SYS.DUMMY
) t (a, b)

-- TERADATA
SELECT t.a, t.b
FROM (
  SELECT 1, 2
  FROM (
    SELECT 1 AS "dual"
  ) AS "dual"
) t (a, b)
 

4.6.2.4. Unnamed derived tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The org.jooq.Table type can reference a derived table:

-- Derived table
(SELECT 1 AS a)
// Derived table
table(select(inline(1).as("a")));

Most databases do not support unnamed derived tables, they require an explicit alias. If you do not provide jOOQ with such an explicit alias, an alias will be generated based on the derived table's content, to make sure the generated SQL will be syntactically correct. The generated alias is not specified and should not be referenced explicitly.

While the actual alias shouldn't be relied upon, as the generation algorithm might change between jOOQ versions, the alias will remain stable per SQL content of the derived table, in order to prevent execution plan cache contention in dialects with an execution plan. In other words, two consecutive renderings of a structurally identical derived table should produce the same generated alias. Of course, it's usually better to provide an explicit alias nonetheless.
 

4.6.3. Joined tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The JOIN operators that can be used in SQL SELECT statements are the most powerful and best supported means of creating new table expressions in SQL.

This section will explain the different types of join:

  • CROSS JOIN: A cross product
  • INNER JOIN: A cross product filtering on matches
  • OUTER JOIN: A cross product filtering on matches, additionally producing some unmatched rows
  • SEMI JOIN: A check for existence of rows from one table in another table (using EXISTS or IN)
  • ANTI JOIN: A check for non-existence of rows from one table in another table (using NOT EXISTS or some conditions NOT IN)

... as well as the different types of forming join predicates:

  • ON: Expressing join predicates explicitly
  • ON KEY: Expressing join predicates explicitly or implicitly based on a FOREIGN KEY
  • USING: Expressing join predicates implicitly based on an explicit set of shared column names in both tables
  • NATURAL: Expressing join predicates implicitly based on an implicit set of shared column names in both tables

... and then, there are additional ways to enrich joins:

  • APPLY or LATERAL: Ordering the join tree from left to right, allowing the right side to access rows from the left side
  • PARTITION BY on OUTER JOIN: To fill the gaps in a report that uses OUTER JOIN

All of these approaches are available twice in the jOOQ API:

  • On the org.jooq.Table API, where they form binary operators
  • On the SELECT API, where they are offered as convenience in jOOQ's DSL, to tame the parentheses
 

4.6.3.1. CROSS JOIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A CROSS JOIN creates a cartesian product or cross product between the two tables it joins. It does not allow for any join predicates to be specified.

It is an occasionally useful operator in reporting, when every element of one set need to be combined with every element of another set. For example, when you want to produce a report combining employees and weekdays, and then do something with the resulting table:

SELECT EMPLOYEE.NAME, WEEKDAY.NAME
FROM EMPLOYEE
CROSS JOIN WEEKDAY
 
create.select(EMPLOYEE.NAME, WEEKDAY.NAME)
      .from(EMPLOYEE)
      .crossJoin(WEEKDAY)
      .fetch();

Some example output might be:

+---------------+--------------+
| EMPLOYEE.NAME | WEEKDAY.NAME |
+---------------+--------------+
| Jon           | Monday       |
| Jon           | Tuesday      |
| Jon           | Wednesday    |
| Jon           | Thursday     |
| Jon           | Friday       |
| Jon           | Saturday     |
| Jon           | Sunday       |
| Jane          | Monday       |
| Jane          | Tuesday      |
| Jane          | Wednesday    |
| Jane          | Thursday     |
| Jane          | Friday       |
| Jane          | Saturday     |
| Jane          | Sunday       |
| ...           | ...          |
+---------------+--------------+

Table lists

Note that a CROSS JOIN is functionally (but not syntactically) equivalent to a table list that you can provide in the FROM clause:

SELECT EMPLOYEE.NAME, WEEKDAY.NAME
FROM EMPLOYEE, WEEKDAY
 
create.select(EMPLOYEE.NAME, WEEKDAY.NAME)
      .from(EMPLOYEE, WEEKDAY)
      .fetch();

It is usually recommended to prefer the CROSS JOIN syntax in order to clearly communicate intent.

Dialect support

This example using jOOQ:

select(BOOK.ID, AUTHOR.ID).from(BOOK.crossJoin(AUTHOR))

Translates to the following dialect specific expressions:

-- ASE
SELECT BOOK.ID, AUTHOR.ID
FROM BOOK
  JOIN AUTHOR
    ON 1 = 1

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
SELECT BOOK.ID, AUTHOR.ID
FROM BOOK
  CROSS JOIN AUTHOR

-- ACCESS, DUCKDB
/* UNSUPPORTED */
 

4.6.3.2. INNER JOIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

An INNER JOIN or just JOIN works like a CROSS JOIN, but adds a predicate of some sort filtering out unwanted combinations. This is the most popular way to join tables, as we hardly ever want to combine arbitrary rows from both tables, but the ones that have some relationship with each other, e.g. a FOREIGN KEY reference match.

SELECT *
FROM AUTHOR
JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The above query will return all authors and their books. True to the nature of an INNER JOIN, authors without books are excluded as well as books without authors (if the FOREIGN KEY is optional).

The result might look like this:

+------------+-----------+--------------+
| FIRST_NAME | LAST_NAME | TITLE        |
+------------+-----------+--------------+
| George     | Orwell    | 1984         |
| George     | Orwell    | Animal Farm  |
| Paulo      | Coelho    | O Alquimista |
| Paulo      | Coelho    | Brida        |
+------------+-----------+--------------+

In the example, we're using the ON clause to form the JOIN predicate, but other options will be discussed in later sections as well.

The INNER keyword is optional both in SQL and in jOOQ, and does not affect the query semantics at all.

Dialect support

This example using jOOQ:

select(BOOK.ID, AUTHOR.ID).from(BOOK.join(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))

Translates to the following dialect specific expressions:

-- ACCESS
SELECT BOOK.ID, AUTHOR.ID
FROM BOOK
  INNER JOIN AUTHOR
    ON BOOK.AUTHOR_ID = AUTHOR.ID

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
SELECT BOOK.ID, AUTHOR.ID
FROM BOOK
  JOIN AUTHOR
    ON BOOK.AUTHOR_ID = AUTHOR.ID
 

4.6.3.3. OUTER JOIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

OUTER JOIN allows for producing some additional rows when an INNER JOIN does not match. There are 3 types of OUTER JOIN:

  • LEFT JOIN or LEFT OUTER JOIN: Always produce all rows from the left side of the join, and only matched rows from the right side of the join
  • RIGHT JOIN or RIGHT OUTER JOIN: Always produce all rows from the right side of the join, and only matched rows from the left side of the join
  • FULL JOIN or FULL OUTER JOIN: Always produce all rows from both left and right side of the join

The OUTER keyword is optional both in SQL and in jOOQ, and does not affect the query semantics at all.

This is best explained by example.

LEFT JOIN

LEFT JOIN is the most popular among the OUTER JOIN types.

The following query produces all authors, and possibly, their books:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  BOOK.TITLE
FROM AUTHOR
LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME,
         BOOK.TITLE)
      .from(AUTHOR)
      .leftJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The result might look like this:

+------------+-----------+--------------+
| FIRST_NAME | LAST_NAME | TITLE        |
+------------+-----------+--------------+
| George     | Orwell    | 1984         |
| George     | Orwell    | Animal Farm  |
| Paulo      | Coelho    | O Alquimista |
| Paulo      | Coelho    | Brida        | <-- Above rows are also produced by INNER JOIN
| Jane       | Austen    |              | <-- This row is only produced by LEFT JOIN or FULL JOIN
+------------+-----------+--------------+

As can be seen, all rows from the left side of the join (authors) are produced, including the ones that do not have any matches on the right side of the join (books). We don't have any books for Jane Austen yet, but Jane Austen is in the result set. She wouldn't be if this were an INNER JOIN.

RIGHT JOIN

RIGHT JOIN is just the inverse of a LEFT JOIN, and is hardly ever used.

The following query produces all books, and possibly, their authors:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  BOOK.TITLE
FROM AUTHOR
RIGHT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME,
         BOOK.TITLE)
      .from(AUTHOR)
      .rightJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The result might look like this:

+------------+-----------+--------------------+
| FIRST_NAME | LAST_NAME | TITLE              |
+------------+-----------+--------------------+
| George     | Orwell    | 1984               |
| George     | Orwell    | Animal Farm        |
| Paulo      | Coelho    | O Alquimista       |
| Paulo      | Coelho    | Brida              | <-- Above rows are also produced by INNER JOIN
|            |           | The Arabian Nights | <-- This row is only produced by RIGHT JOIN or FULL JOIN
+------------+-----------+--------------------+

As can be seen, all rows from the right side of the join (books) are produced, including the ones that do not have any matches on the left side of the join (authors). The Arabian Night does not have a specific author, but it is still in the result set. It wouldn't be if this were an INNER JOIN.

Not that a RIGHT JOIN is just an inversed LEFT JOIN, and you would be much more likely to write the same query like this, with no semantic difference:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  BOOK.TITLE
FROM BOOK
LEFT JOIN AUTHOR ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME,
         BOOK.TITLE)
      .from(BOOK)
      .leftJoin(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

There are complex join trees where a RIGHT JOIN may make things simpler, but in most cases, it only complicates readability and maintainability of your query.

FULL JOIN

FULL JOIN is an occasionally useful way to join two tables when no rows from either table should be omitted. This can be useful e.g. to compare two data sets.

The following query produces all authors and all books:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  BOOK.TITLE
FROM AUTHOR
FULL JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME,
         BOOK.TITLE)
      .from(AUTHOR)
      .fullJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The result might look like this:

+------------+-----------+--------------------+
| FIRST_NAME | LAST_NAME | TITLE              |
+------------+-----------+--------------------+
| George     | Orwell    | 1984               |
| George     | Orwell    | Animal Farm        |
| Paulo      | Coelho    | O Alquimista       |
| Paulo      | Coelho    | Brida              | <-- Above rows are also produced by INNER JOIN
| Jane       | Austen    |                    | <-- This row is only produced by LEFT JOIN or FULL JOIN
|            |           | The Arabian Nights | <-- This row is only produced by RIGHT JOIN or FULL JOIN
+------------+-----------+--------------------+

As can be seen, all rows from the left side of the join (authors) as well as from the right side of the join (books) are produced, including the ones that do not have any matches on the respective other side of the join.

Dialect support

This example using jOOQ:

select(BOOK.ID, AUTHOR.ID).from(BOOK.leftJoin(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))

Translates to the following dialect specific expressions:

-- All dialects
SELECT BOOK.ID, AUTHOR.ID
FROM BOOK
  LEFT OUTER JOIN AUTHOR
    ON BOOK.AUTHOR_ID = AUTHOR.ID
 

4.6.3.4. SEMI JOIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Relational algebra defines a SEMI JOIN operation that regrettably didn't make it into standard SQL (yet), though it is easy to emulate using the EXISTS predicate or IN predicate, which is what most people are doing.

jOOQ offers a convenient LEFT SEMI JOIN operator to match the relational algebra semantics. The following query will produce all authors that have books (but doesn't produce any books):

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME
FROM AUTHOR
WHERE EXISTS (
  SELECT * FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID
)
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME
      )
      .from(AUTHOR)
      .leftSemiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The result might look like this:

+------------+-----------+
| FIRST_NAME | LAST_NAME |
+------------+-----------+
| George     | Orwell    |
| Paulo      | Coelho    |
+------------+-----------+

Of course, you can form an equivalent query using EXISTS or IN as well in jOOQ. It is also possible to achieve SEMI JOIN semantics by using an INNER JOIN, and possibly the SELECT DISTINCT clause, but chances are, that query is slower and incorrect (e.g. removing too many distinct rows). A SEMI JOIN both using jOOQ's convenience syntax or the equivalent SQL emulation using EXISTS or IN are semantically more precise and should be preferred.

SEMI JOIN is the inverse of the ANTI JOIN operator.

Dialect support

This example using jOOQ:

select(AUTHOR.ID).from(AUTHOR).leftSemiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))

Translates to the following dialect specific expressions:

-- All dialects
SELECT AUTHOR.ID
FROM AUTHOR
WHERE EXISTS (
  SELECT 1 one
  FROM BOOK
  WHERE BOOK.AUTHOR_ID = AUTHOR.ID
)
 

4.6.3.5. ANTI JOIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Relational algebra defines a ANTI JOIN operation that regrettably didn't make it into standard SQL (yet), though it is easy to emulate using the NOT EXISTS predicate. Unlike SEMI JOIN, it is not advised to use the NOT IN predicate to emulate ANTI JOIN, because that risks being incorrect in the presence of NULL values, a mistake that can be very subtle and thus hard to find.

jOOQ offers a convenient LEFT ANTI JOIN operator to match the relational algebra semantics. The following query will produce all authors that have no books:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME
FROM AUTHOR
WHERE NOT EXISTS (
  SELECT * FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID
)
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME
      )
      .from(AUTHOR)
      .leftAntiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

The result might look like this, i.e. we might have an author Jane Austen in our database, but we don't have any books for her yet:

+------------+-----------+
| FIRST_NAME | LAST_NAME |
+------------+-----------+
| Jane       | Austen    |
+------------+-----------+

Of course, you can form an equivalent query using NOT EXISTS as well in jOOQ. It is also possible to achieve ANTI JOIN semantics by using an LEFT JOIN and a NULL predicate on the anti joined table's primary key placed outside of the ON clause, though that might be a bit esoteric and hard to read:

SELECT
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME
FROM AUTHOR
LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
WHERE BOOK.ID IS NULL
 
create.select(
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .leftJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .where(BOOK.ID.isNull())
      .fetch();

Think of the LEFT JOIN example result:

+------------+-----------+--------------+
| FIRST_NAME | LAST_NAME | TITLE        |
+------------+-----------+--------------+
| George     | Orwell    | 1984         |
| George     | Orwell    | Animal Farm  |
| Paulo      | Coelho    | O Alquimista |
| Paulo      | Coelho    | Brida        | <-- Reject all of the above where we have BOOK.ID IS NOT NULL
| Jane       | Austen    |              | <-- Keep only this row, where BOOK.ID IS NULL
+------------+-----------+--------------+

As can be seen, no DISTINCT is required to remove duplicates, because there's always only 1 row for an author without books.

ANTI JOIN is the inverse of the SEMI JOIN operator.

Dialect support

This example using jOOQ:

select(AUTHOR.ID).from(AUTHOR).leftAntiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))

Translates to the following dialect specific expressions:

-- All dialects
SELECT AUTHOR.ID
FROM AUTHOR
WHERE NOT EXISTS (
  SELECT 1 one
  FROM BOOK
  WHERE BOOK.AUTHOR_ID = AUTHOR.ID
)
 

4.6.3.6. ON clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.

One way to supply this join predicate is the ON clause, which offers most flexibility. The following example shows how to "equi join" the author and books tables based on their FOREIGN KEY relationship:

SELECT *
FROM AUTHOR
JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

But in most dialects, any type of join predicate is possible in ON to specify what rows should be produced by the join operation. Note that while for INNER JOIN, the predicates in the ON clause and the predicates in the WHERE clause have the same effect, this isn't true for all the other join types, including OUTER JOIN, SEMI JOIN, ANTI JOIN. For example, the following query will list all authors and their books, but only if the book was published before the year 1950:

SELECT *
FROM AUTHOR
LEFT JOIN BOOK
  ON BOOK.AUTHOR_ID = AUTHOR.ID
  AND BOOK.PUBLISHED_IN < 1950
 
create.select()
      .from(AUTHOR)
      .leftJoin(BOOK)
        .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
        .and(BOOK.PUBLISHED_IN.lt(1950))
      .fetch();

The result might look like this:

+------------+-----------+--------------+
| FIRST_NAME | LAST_NAME | TITLE        |
+------------+-----------+--------------+
| George     | Orwell    | 1984         |
| George     | Orwell    | Animal Farm  | <-- This author's books were all published before 1950
| Paulo      | Coelho    |              | <-- This author's books were published after 1950
+------------+-----------+--------------+

We still get all the authors, but only the books that fulfil the ON predicate. This is very different from putting that additional predicate in the WHERE clause:

SELECT *
FROM AUTHOR
LEFT JOIN BOOK
  ON BOOK.AUTHOR_ID = AUTHOR.ID
WHERE BOOK.PUBLISHED_IN < 1950
 
create.select()
      .from(AUTHOR)
      .leftJoin(BOOK)
        .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .where(BOOK.PUBLISHED_IN.lt(1950))
      .fetch();

The result might now look like this:

+------------+-----------+--------------+
| FIRST_NAME | LAST_NAME | TITLE        |
+------------+-----------+--------------+
| George     | Orwell    | 1984         |
| George     | Orwell    | Animal Farm  | <-- This author's books were all published before 1950
+------------+-----------+--------------+

Now the predicate is applied after the join operator, not as a part of the join operator, so it's just an ordinary predicate.

 

4.6.3.7. ON KEY clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ON KEY clause can quickly produce ambiguities as the implicit key path between two tables in a complex join tree isn't always unique. This can even happen for queries that have worked in the past, but due to new FOREIGN KEY constraints being added to tables, will stop working. Use this clause with caution!

All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.

One way to supply this join predicate is the ON KEY clause, which allows for conveniently joining two tables based on their FOREIGN KEY relationship, assuming the relevant meta data is known to jOOQ via code generation:

SELECT *
FROM AUTHOR
JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .join(BOOK).onKey()
      .fetch();

There are different overloads of this onKey() method. The above one is applicable when there are no ambiguous paths between the two joined tables. If there are several FOREIGN KEY declarations (e.g. a book has an AUTHOR_ID and a CO_AUTHOR_ID), then you can pass the org.jooq.ForeignKey reference to the method, instead, to resolve the ambiguity.

SELECT *
FROM AUTHOR
JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .join(BOOK).onKey(Keys.FK_BOOK_AUTHOR)
      .fetch();
 

4.6.3.8. USING clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The USING clause can quickly produce ambiguities as the column names between two tables in a complex join tree aren't always unique. This can even happen for queries that have worked in the past, but due to new columns being added to tables, will stop working. Use this clause with caution!

All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.

One way to supply this join predicate is the USING clause, which allows for specifying a set of column names that are common to both tables, based on which to form a join predicate. Assuming we called our AUTHOR.ID column AUTHOR.AUTHOR_ID instead:

SELECT *
FROM AUTHOR
JOIN BOOK USING (AUTHOR_ID)
 
create.select()
      .from(AUTHOR)
      .join(BOOK).using(AUTHOR.AUTHOR_ID)
      .fetch();

There is a certain risk of ambiguities as well in more complex join trees, but in simple cases, this can be a very convenient way to join tables if you design your schema accordingly. The is a good example where all FOREIGN KEY columns share the referenced PRIMARY KEY column's names.

 

4.6.3.9. NATURAL clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The NATURAL KEY operator can quickly produce ambiguities as the column names between two tables in a complex join tree aren't always unique, nor should they be included in a JOIN predicate (e.g. LAST_UPDATE or other technical columns, present on every table). This can even happen for queries that have worked in the past, but due to new columns being added to tables, will stop working. In fact, it's very hard to design a schema to allow for using NATURAL JOIN. Use this clause with caution!

All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.

One way to supply this join predicate is the NATURAL clause, which works like USING clause, except that it discovers shared column names implicitly from the table metadata. Assuming we called our AUTHOR.ID column AUTHOR.AUTHOR_ID instead:

SELECT *
FROM AUTHOR
NATURAL JOIN BOOK
 
create.select()
      .from(AUTHOR)
      .naturalJoin(BOOK)
      .fetch();

There is a high risk of ambiguities even in simple join trees, which is why this syntax is hardly ever used. It can be very rarely useful combined with FULL JOIN to form a NATURAL FULL JOIN, which can create a sort of SQL-style untagged union type between two row types. A bit esoteric for every day usage.

 

4.6.3.10. LATERAL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

LATERAL is a SQL standard table operator to wrap derived tables (or other table expressions, in some dialects), such that the tables and columns declared before the LATERAL derived table become in scope. See APPLY for an alternative, SQL Server specific syntax.

An example:

SELECT *
FROM
  AUTHOR,

  -- All previous objects (i.e. AUTHOR)
  -- are now in scope for the following subquery
  LATERAL (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID -- AUTHOR is in scope
  );
DSL.using(configuration)
   .select()
   .from(
      AUTHOR,
      lateral(
        select(count()
        .from(BOOK)
        .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
      )
   )
   .fetch();

This is most useful for:

Dialect support

This example using jOOQ:

select().from(AUTHOR, lateral(selectCount().from(BOOK).where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, MYSQL, ORACLE, POSTGRES, SNOWFLAKE, SYBASE, TRINO, YUGABYTEDB
SELECT
  AUTHOR.ID,
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  AUTHOR.DATE_OF_BIRTH,
  AUTHOR.YEAR_OF_BIRTH,
  AUTHOR.DISTINGUISHED,
  alias_124651337.count
FROM
  AUTHOR,
  LATERAL (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID
  ) alias_124651337

-- SQLDATAWAREHOUSE, SQLSERVER
SELECT
  AUTHOR.ID,
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  AUTHOR.DATE_OF_BIRTH,
  AUTHOR.YEAR_OF_BIRTH,
  AUTHOR.DISTINGUISHED,
  alias_124651337.count
FROM AUTHOR
  CROSS APPLY (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID
  ) alias_124651337

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, REDSHIFT, 
-- SQLITE, TERADATA, VERTICA
/* UNSUPPORTED */
 

4.6.3.11. APPLY

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

APPLY (specifically, CROSS APPLY or OUTER APPLY) is the SQL Server specific syntax for the SQL standard LATERAL derived table syntax.

An example:

SELECT *
FROM
  AUTHOR

  -- All previous objects (i.e. AUTHOR)
  -- are now in scope for the following subquery
  CROSS APPLY (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID -- AUTHOR is in scope
  );
DSL.using(configuration)
   .select()
   .from(
      AUTHOR
      .crossApply(
        select(count()
        .from(BOOK)
        .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
      )
   )
   .fetch();

This is most useful for:

Dialect support

This example using jOOQ:

selectFrom(AUTHOR.crossApply(selectCount().from(BOOK).where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, POSTGRES, SNOWFLAKE, TRINO, YUGABYTEDB
SELECT
  AUTHOR.ID,
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  AUTHOR.DATE_OF_BIRTH,
  AUTHOR.YEAR_OF_BIRTH,
  AUTHOR.DISTINGUISHED,
  alias_124651337.count
FROM AUTHOR
  CROSS JOIN LATERAL (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID
  ) alias_124651337

-- BIGQUERY, ORACLE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE
SELECT
  AUTHOR.ID,
  AUTHOR.FIRST_NAME,
  AUTHOR.LAST_NAME,
  AUTHOR.DATE_OF_BIRTH,
  AUTHOR.YEAR_OF_BIRTH,
  AUTHOR.DISTINGUISHED,
  alias_124651337.count
FROM AUTHOR
  CROSS APPLY (
    SELECT count(*)
    FROM BOOK
    WHERE BOOK.AUTHOR_ID = AUTHOR.ID
  ) alias_124651337

-- ACCESS, ASE, AURORA_MYSQL, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLITE, 
-- TERADATA, VERTICA
/* UNSUPPORTED */
 

4.6.3.12. PARTITION BY

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Standard SQL (e.g. implemented by Oracle) ships with a special syntax available for OUTER JOIN clauses. This can be used to fill gaps for simplified analytical calculations. jOOQ only supports putting the PARTITION BY clause to the right of the OUTER JOIN clause. The following example will create at least one record per AUTHOR and per existing value in BOOK.PUBLISHED_IN, regardless if an AUTHOR has actually published a book in that year.

SELECT *
FROM AUTHOR
LEFT OUTER JOIN BOOK
PARTITION BY (PUBLISHED_IN)
ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .leftOuterJoin(BOOK)
      .partitionBy(BOOK.PUBLISHED_IN)
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();
 

4.6.4. The VALUES() table constructor

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some databases allow for expressing in-memory temporary tables using a VALUES() constructor. This constructor usually works the same way as the VALUES() clause known from the INSERT statement or from the MERGE statement. With jOOQ, you can also use the VALUES() table constructor, to create tables that can be used in a SELECT statement's FROM clause:

SELECT a, b
FROM VALUES(1, 'a'),
           (2, 'b') t(a, b)
 
create.select()
      .from(values(row(1, "a"),
                   row(2, "b")).as("t", "a", "b"))
      .fetch();

Note, that it is usually quite useful to provide column aliases ("derived column lists") along with the table alias for the VALUES() constructor.

The above statement is emulated by jOOQ for those databases that do not support the VALUES() constructor, natively (actual emulations may vary):

-- If derived column expressions are supported:
SELECT a, b
FROM (
  SELECT 1, 'a' FROM DUAL UNION ALL
  SELECT 2, 'b' FROM DUAL
) t(a, b)

-- If derived column expressions are not supported:
SELECT a, b
FROM (

  -- An empty dummy record is added to provide column names for the emulated derived column expression
  SELECT NULL a, NULL b FROM DUAL WHERE 1 = 0 UNION ALL

  -- Then, the actual VALUES() constructor is emulated
  SELECT 1,      'a'    FROM DUAL             UNION ALL
  SELECT 2,      'b'    FROM DUAL
) t
 

4.6.5. Derived tables

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A derived table is a nested SELECT in the FROM clause, i.e. it can be used as a table expression. As such, it works differently from a scalar subquery, which is a column expression.

 

SELECT nested.* FROM (
      SELECT AUTHOR_ID, count(*) books
        FROM BOOK
    GROUP BY AUTHOR_ID
) nested
ORDER BY nested.books DESC
 
Table<?> nested =
    create.select(BOOK.AUTHOR_ID, count().as("books"))
          .from(BOOK)
          .groupBy(BOOK.AUTHOR_ID).asTable("nested");

create.select(nested.fields())
      .from(nested)
      .orderBy(nested.field("books"))
      .fetch();
 

4.6.6. The Oracle 11g PIVOT clause

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

If you are closely coupling your application to an Oracle database, you can take advantage of some Oracle-specific features, such as the PIVOT clause, used for statistical analyses. The formal syntax definition is as follows:

-- SELECT ..
     FROM table PIVOT (aggregateFunction [, aggregateFunction] FOR column IN (expression [, expression]))
--  WHERE ..

The PIVOT clause is available from the org.jooq.Table type, as pivoting is done directly on a table. Currently, only Oracle's PIVOT clause is supported. Support for SQL Server's slightly different PIVOT clause will be added later. Also, jOOQ may emulate PIVOT for other dialects in the future.

 

4.6.7. jOOQ's relational division syntax

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

There is one operation in relational algebra that is not given a lot of attention, because it is rarely used in real-world applications. It is the relational division, the opposite operation of the cross product (or, relational multiplication). The following is an approximate definition of a relational division:

Assume the following cross join / cartesian product
C = A × B

Then it can be said that
A = C ÷ B
B = C ÷ A

With jOOQ, you can simplify using relational divisions by using the following syntax:

C.divideBy(B).on(C.ID.eq(B.C_ID)).returning(C.TEXT)

The above roughly translates to

SELECT DISTINCT C.TEXT FROM C "c1"
WHERE NOT EXISTS (
  SELECT 1 FROM B
  WHERE NOT EXISTS (
    SELECT 1 FROM C "c2"
    WHERE "c2".TEXT = "c1".TEXT
    AND "c2".ID = B.C_ID
  )
)

Or in plain text: Find those TEXT values in C whose ID's correspond to all ID's in B. Note that from the above SQL statement, it is immediately clear that proper indexing is of the essence. Be sure to have indexes on all columns referenced from the on(...) and returning(...) clauses.

For more information about relational division and some nice, real-life examples, see

 

4.6.8. Array and cursor unnesting

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard specifies how SQL databases should implement ARRAY and TABLE types, as well as CURSOR types. Put simply, a CURSOR is a pointer to any materialised table expression. Depending on the cursor's features, this table expression can be scrolled through in both directions, records can be locked, updated, removed, inserted, etc. Often, CURSOR types contain s, whereas ARRAY and TABLE types contain simple scalar values, although that is not a requirement

ARRAY types in SQL are similar to Java's array types. They contain a "component type" or "element type" and a "dimension". This sort of ARRAY type is implemented in H2, HSQLDB and Postgres and supported by jOOQ as such. Oracle uses strongly-typed arrays, which means that an ARRAY type (VARRAY or TABLE type) has a name and possibly a maximum capacity associated with it.

Unnesting array and cursor types

The real power of these types become more obvious when you fetch them from stored procedures to unnest them as table expressions and use them in your FROM clause. An example is given here, where Oracle's DBMS_XPLAN package is used to fetch a cursor containing data about the most recent execution plan:

SELECT *
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(null, null, 'ALLSTATS'));
 
create.select()
      .from(table(DbmsXplan.displayCursor(null, null, "ALLSTATS"))
      .fetch();

Note, in order to access the DbmsXplan package, you can use the code generator to generate Oracle's SYS schema.

 

4.6.9. Table-valued functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some databases support functions that can produce tables for use in arbitrary SELECT statements. jOOQ supports these functions out-of-the-box for such databases. For instance, in SQL Server, the following function produces a table of (ID, TITLE) columns containing either all the books or just one book by ID:

CREATE FUNCTION f_books (@id INTEGER)
RETURNS @out_table TABLE (
    id INTEGER,
    title VARCHAR(400)
)
AS
BEGIN
    INSERT @out_table
    SELECT id, title
    FROM book
    WHERE @id IS NULL OR id = @id
    ORDER BY id
    RETURN
END

The jOOQ code generator will now produce a generated table from the above, which can be used as a SQL function:

// Fetching all books records
Result<FBooksRecord> r1 = create.selectFrom(fBooks(null)).fetch();

// Lateral joining the table-valued function to another table using CROSS APPLY:
create.select(BOOK.ID, F_BOOKS.TITLE)
      .from(BOOK.crossApply(fBooks(BOOK.ID)))
      .fetch();
 

4.6.10. GENERATE_SERIES

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A nice built-in table-valued function from the PostgreSQL dialect is the GENERATE_SERIES() function, which allows for creating a table for a range of numeric values. Many dialects have some way of generating such a table, and if not, it can be emulated using recursive SQL.

// Values from 1 to 10
Result<Record1<Integer>> r = create.selectFrom(generateSeries(1, 10)).fetch();

Dialect support

This example using jOOQ:

selectFrom(generateSeries(1, 10))

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DUCKDB, POSTGRES, YUGABYTEDB
SELECT generate_series.generate_series
FROM generate_series(1, 10)

-- BIGQUERY
SELECT generate_series.generate_series
FROM (
  SELECT null generate_series
  FROM UNNEST([STRUCT(1 AS dual)]) AS dual
  WHERE FALSE
  UNION ALL
  SELECT *
  FROM unnest(generate_array(1, 10)) generate_series
) generate_series

-- COCKROACHDB
SELECT generate_series.generate_series
FROM generate_series(1, 10) generate_series (generate_series)

-- DB2
SELECT generate_series.generate_series
FROM (
  WITH
    generate_series(generate_series) AS (
      SELECT 1
      FROM SYSIBM.DUAL
      UNION ALL
      SELECT (generate_series + 1)
      FROM generate_series
      WHERE generate_series < 10
    )
  SELECT generate_series
  FROM generate_series
) generate_series

-- EXASOL, ORACLE
SELECT generate_series.generate_series
FROM (
  SELECT (level + (1 - 1)) generate_series
  FROM DUAL
  CONNECT BY level <= ((10 + 1) - 1)
) generate_series

-- FIREBIRD
SELECT generate_series.generate_series
FROM (
  WITH RECURSIVE
    generate_series(generate_series) AS (
      SELECT 1
      FROM RDB$DATABASE
      UNION ALL
      SELECT (generate_series + 1)
      FROM generate_series
      WHERE generate_series < 10
    )
  SELECT generate_series
  FROM generate_series
) generate_series

-- H2
SELECT generate_series.generate_series
FROM system_range(1, 10) generate_series (generate_series)

-- HSQLDB
SELECT generate_series.generate_series
FROM (
  WITH RECURSIVE
    generate_series(generate_series) AS (
      SELECT 1
      FROM (VALUES(1)) AS dual(dual)
      UNION ALL
      SELECT (generate_series + 1)
      FROM generate_series
      WHERE generate_series < 10
    )
  SELECT generate_series
  FROM generate_series
) generate_series

-- INFORMIX
SELECT generate_series.generate_series
FROM (
  SELECT (level + (1 - 1)) generate_series
  FROM (
    SELECT 1 AS dual
    FROM systables
    WHERE (tabid = 1)
  ) AS dual
  CONNECT BY level <= ((10 + 1) - 1)
) generate_series

-- MARIADB, MYSQL, SQLITE, TRINO
SELECT generate_series.generate_series
FROM (
  WITH RECURSIVE
    generate_series(generate_series) AS (
      SELECT 1
      UNION ALL
      SELECT (generate_series + 1)
      FROM generate_series
      WHERE generate_series < 10
    )
  SELECT generate_series
  FROM generate_series
) generate_series

-- SNOWFLAKE
SELECT generate_series.generate_series
FROM (
  SELECT ((seq4() + 1) + (1 - 1)) generate_series
  FROM TABLE(generator(rowcount => (10 - (1 - 1))))
) generate_series (generate_series)

-- SQLDATAWAREHOUSE
WITH
  generate_series(generate_series) AS (
    SELECT 1
    UNION ALL
    SELECT (generate_series + 1)
    FROM generate_series
    WHERE generate_series < 10
  )
SELECT generate_series.generate_series
FROM (
  SELECT generate_series
  FROM generate_series
) generate_series

-- SQLSERVER
SELECT generate_series.generate_series
FROM (
  SELECT *
  FROM generate_series(1, 10)
) generate_series (generate_series)

-- SYBASE
SELECT generate_series.generate_series
FROM (
  WITH RECURSIVE
    generate_series(generate_series) AS (
      SELECT 1
      FROM SYS.DUMMY
      UNION ALL
      SELECT (generate_series + 1)
      FROM generate_series
      WHERE generate_series < 10
    )
  SELECT generate_series
  FROM generate_series
) generate_series

-- TERADATA
WITH RECURSIVE
  generate_series(generate_series) AS (
    SELECT 1
    FROM (
      SELECT 1 AS "dual"
    ) AS "dual"
    UNION ALL
    SELECT (generate_series + 1)
    FROM generate_series
    WHERE generate_series < 10
  )
SELECT generate_series.generate_series
FROM (
  SELECT generate_series
  FROM generate_series
) generate_series

-- ACCESS, ASE, AURORA_MYSQL, DERBY, HANA, MEMSQL, REDSHIFT, VERTICA
/* UNSUPPORTED */
 

4.6.11. The DUAL table

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard specifies that the FROM clause is mandatory in a SELECT statement. However, in the real world, there exist three types of databases:

  • The ones that always require a FROM clause (as required by the SQL standard)
  • The ones that never require a FROM clause (and still allow a WHERE clause)
  • The ones that require a FROM clause only with a WHERE clause, GROUP BY clause, or HAVING clause

With jOOQ, you don't have to worry about the above distinction of SQL dialects. jOOQ never requires a FROM clause, but renders the necessary "DUAL" table, if needed. The following program shows how jOOQ renders "DUAL" tables

Dialect support

This example using jOOQ:

select(inline(1))

Translates to the following dialect specific expressions:

-- ACCESS
SELECT 1
FROM (
  SELECT count(*) dual
  FROM MSysResources
) AS dual

-- ASE, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, TRINO, VERTICA, YUGABYTEDB
SELECT 1

-- AURORA_MYSQL, MEMSQL
SELECT 1
FROM DUAL

-- DB2
SELECT 1
FROM SYSIBM.DUAL

-- DERBY
SELECT 1
FROM SYSIBM.SYSDUMMY1

-- FIREBIRD
SELECT 1
FROM RDB$DATABASE

-- HANA, SYBASE
SELECT 1
FROM SYS.DUMMY

-- HSQLDB
SELECT 1
FROM (VALUES(1)) AS dual(dual)

-- INFORMIX
SELECT 1
FROM (
  SELECT 1 AS dual
  FROM systables
  WHERE (tabid = 1)
) AS dual

-- TERADATA
SELECT 1
FROM (
  SELECT 1 AS "dual"
) AS "dual"

Note, that some databases (H2, MySQL) can normally do without "DUAL". However, there exist some corner-cases with complex nested SELECT statements, where this will cause syntax errors (or parser bugs). To stay on the safe side, jOOQ will always render "dual" in those dialects.

 

4.7. Column expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Column expressions can be used in various SQL clauses in order to refer to one or several columns. This chapter explains how to form various types of column expressions with jOOQ. A particular type of column expression is given in the section about tuples or row value expressions, where an expression may have a degree of more than one.

Using column expressions in jOOQ

jOOQ allows you to freely create arbitrary column expressions using a fluent expression construction API. Many expressions can be formed as functions from DSL methods, other expressions can be formed based on a pre-existing column expression. For example:

// A regular table column expression
Field<String> field1 = BOOK.TITLE;

// A function created from the DSL
Field<String> field2 = trim(BOOK.TITLE);

// More complex function with advanced DSL syntax
Field<String> field4 = listAgg(BOOK.TITLE)
                          .withinGroupOrderBy(BOOK.ID.asc())
                          .over().partitionBy(AUTHOR.ID);
 

4.7.1. Table columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Table columns are the most simple implementations of a column expression. They are mainly produced by jOOQ's code generator and can be dereferenced from the generated tables, but other ways of creating table column references are possible.

 

4.7.1.1. Generated table columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The main type of column expression are the ones produced by jOOQ's code generator and can be dereferenced from the generated tables. This manual is full of examples involving table columns. Another example is given in this query:

SELECT BOOK.ID, BOOK.TITLE
FROM BOOK
WHERE BOOK.TITLE LIKE '%SQL%'
ORDER BY BOOK.TITLE
 
create.select(BOOK.ID, BOOK.TITLE)
      .from(BOOK)
      .where(BOOK.TITLE.like("%SQL%"))
      .orderBy(BOOK.TITLE)
      .fetch();

Table columns implement a more specific interface called org.jooq.TableField, which is parameterised with its associated <R extends Record> record type, and provides access to the container org.jooq.Table instance.

See the manual's section about generated tables for more information about what is really generated by the code generator

 

4.7.1.2. Dereferenced table columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Any org.jooq.Table instance that is constructed in a way to know its own columns can be used to dereference those columns. Examples include:

All of these table expressions, as well as some others, extend the org.jooq.Fields type, which allows for all of these field accessing types, like org.jooq.Table but also org.jooq.Record and others to share field accessing logic.

// Get fields from AUTHOR dynamically, without type safety:
Field<?> id = AUTHOR.field("ID");
Field<?> firstName = AUTHOR.field("FIRST_NAME");
 

4.7.1.3. Named table columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

When no org.jooq.Table instance is available to dereference a column from, the column expression can still be constructed on the fly, dynamically using a Name reference, and optionally a org.jooq.DataType reference:

// Get fields from AUTHOR dynamically, without type safety:
Field<?> id = field(name("AUTHOR", "ID"));
Field<String> firstName = field(name("AUTHOR", "FIRST_NAME"), INTEGER);

Note that by default, these names are quoted (among other reasons to prevent SQL injection), and thus case sensitive. For more details, please refer to the section about names and identifiers.

 

4.7.2. Aliased columns

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Just like tables, columns can be renamed using aliases. Here is an example:

  SELECT FIRST_NAME || ' ' || LAST_NAME author, COUNT(*) books
    FROM AUTHOR
    JOIN BOOK ON AUTHOR.ID = AUTHOR_ID
GROUP BY FIRST_NAME, LAST_NAME;

Here is how it's done with jOOQ:

Record record = create.select(
         concat(AUTHOR.FIRST_NAME, inline(" "), AUTHOR.LAST_NAME).as("author"),
         count().as("books"))
      .from(AUTHOR)
      .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
      .groupBy(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .fetchAny();

When you alias Fields like above, you can access those Fields' values using the alias name:

System.out.println("Author : " + record.getValue("author"));
System.out.println("Books  : " + record.getValue("books"));

Unnamed column expressions

In most SQL databases, aliasing of column expressions in top level selects is optional. The database will generate a column name that is roughly based on the expression for documentation purposes (e.g. when running the query in a tool like SQL Developer), but applications cannot rely on the name explicitly. This is not a problem as columns can still be referenced by index.

In a similar fashion, jOOQ will assume an unspecified, generated column name for column expressions, based on their content.

-- Arithmetic expression
1 + 2

-- Correlated subquery
(SELECT 1 AS a)
// Arithmetic expression
inline(1).plus(inline(2));

// Correlated subquery
field(select(inline(1).as("a")));

These unnamed expressions can be used both in SQL as well as with jOOQ. However, do note that jOOQ will use Field.getName() to extract this column name from the field, when referencing the field or when nesting it in derived tables. In order to stay in full control of any such column names, it is always a good idea to provide explicit aliasing for column expressions, both in SQL as well as in jOOQ.

Rendering declarations or references

The same aliased column instance is rendered differently depending on where it is placed in the jOOQ expression tree. See the manual's section about rendering declarations vs references for more details.

 

4.7.3. Cast expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

jOOQ's source code generator tries to find the most accurate type mapping between your vendor-specific data types and a matching Java type. For instance, most VARCHAR, CHAR, CLOB types will map to String. Most BINARY, BYTEA, BLOB types will map to byte[]. NUMERIC types will default to java.math.BigDecimal, but can also be any of java.math.BigInteger, java.lang.Long, java.lang.Integer, java.lang.Short, java.lang.Byte, java.lang.Double, java.lang.Float.

Sometimes, this automatic mapping might not be what you needed, or jOOQ cannot know the type of a field. In those cases you would write SQL type CAST like this:

-- Let's say, your Postgres column LAST_NAME was VARCHAR(30)
-- Then you could do this:
SELECT CAST(AUTHOR.LAST_NAME AS TEXT) FROM DUAL

in jOOQ, you can write something like that:

create.select(AUTHOR.LAST_NAME.cast(VARCHAR(100))).fetch();

The same thing can be achieved by casting a Field directly to String.class, as VARCHAR is the default SQLDataType to map to Java's String

create.select(AUTHOR.LAST_NAME.cast(String.class)).fetch();

The complete CAST API in org.jooq.Field consists of these three methods:

public interface Field<T> {

    // Cast this field to the type of another field
    <Z> Field<Z> cast(Field<Z> field);

    // Cast this field to a given DataType
    <Z> Field<Z> cast(DataType<Z> type);

    // Cast this field to the default DataType for a given Class
    <Z> Field<Z> cast(Class<? extends Z> type);
}

// And additional convenience methods in the DSL:
public class DSL {
    <T> Field<T> cast(Object object, Field<T> field);
    <T> Field<T> cast(Object object, DataType<T> type);
    <T> Field<T> cast(Object object, Class<? extends T> type);
    <T> Field<T> castNull(Field<T> field);
    <T> Field<T> castNull(DataType<T> type);
    <T> Field<T> castNull(Class<? extends T> type);
}

Dialect support

This example using jOOQ:

cast("1", VARCHAR(10))

Translates to the following dialect specific expressions:

-- ACCESS
cstr('1')

-- ASE, AURORA_POSTGRES, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
CAST('1' AS varchar(10))

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
CAST('1' AS char(10))

-- BIGQUERY
CAST('1' AS string)

-- COCKROACHDB
CAST('1' AS string(10))

-- INFORMIX
CAST('1' AS lvarchar(10))

-- ORACLE
CAST('1' AS varchar2(10))
 

4.7.4. Datatype coercions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A slightly different use case than CAST expressions are data type coercions, which are not rendered through to generated SQL. Sometimes, you may want to pretend that a numeric value is really treated as a string value, for instance when binding a numeric bind value:

Field<String>  field1 = val(1).coerce(String.class);
Field<Integer> field2 = val("1").coerce(Integer.class);

In the above example, field1 will be treated by jOOQ as a Field<String>, binding the numeric literal 1 as a VARCHAR value. The same applies to field2, whose string literal "1" will be bound as an INTEGER value.

This technique is better than performing unsafe or rawtype casting in Java, if you cannot access the "right" field type from any given expression.

 

4.7.5. Arithmetic expressions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Numeric arithmetic expressions

Your database can do the math for you. Arithmetic operations are implemented just like numeric functions, with similar limitations as far as type restrictions are concerned. You can use any of these operators:

  +  -  *  /  %

In order to express a SQL query like this one:

SELECT ((1 + 2) * (5 - 3) / 2) % 10 FROM DUAL

You can write something like this in jOOQ:

create.select(val(1).add(2).mul(val(5).sub(3)).div(2).mod(10)).fetch();

Operator precedence

jOOQ does not know any operator precedence (see also boolean operator precedence). All operations are evaluated from left to right, as with any object-oriented API. The two following expressions are the same:

   val(1).add(2) .mul(val(5).sub(3)) .div(2) .mod(10);
(((val(1).add(2)).mul(val(5).sub(3))).div(2)).mod(10);

Datetime arithmetic expressions

jOOQ also supports the Oracle-style syntax for adding days to a Field<? extends java.util.Date>

SELECT SYSDATE + 3 FROM DUAL;
create.select(currentTimestamp().add(3)).fetch();

For more advanced datetime arithmetic, use the DSL's timestampDiff() and dateDiff() functions, as well as jOOQ's built-in SQL standard INTERVAL data type support:

 

4.7.6. String concatenation

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard defines the concatenation operator to be an infix operator, similar to the ones we've seen in the chapter about arithmetic expressions. This operator looks like this: ||. Some other dialects do not support this operator, but expect a concat() function, instead. jOOQ renders the right operator / function, depending on your SQL dialect:

SELECT 'A' || 'B' || 'C' FROM DUAL
-- Or in MySQL:
SELECT concat('A', 'B', 'C') FROM DUAL
 
// For all RDBMS, including MySQL:
create.select(concat("A", "B", "C")).fetch();
 

4.7.7. Case sensitivity with strings

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Most databases allow for specifying a COLLATION which allows for re-defining the ordering of string values. By default, ASCII, ISO, or Unicode encodings are applied to character data, and ordering is applied according to the respective encoding.

Sometimes, however, certain queries like to ignore parts of the encoding by treating upper-case and lower-case characters alike, such that ABC = abc, or such that ABC, jkl, XyZ are an ordered list of strings (case-insensitively).

For these ad-hoc ordering use-cases, most people resort to using LOWER() or UPPER() as follows:

-- Case-insensitive filtering:
SELECT * FROM BOOK
WHERE upper(TITLE) = 'ANIMAL FARM'

-- Case-insensitive ordering:
SELECT *
FROM AUTHOR
ORDER BY upper(FIRST_NAME), upper(LAST_NAME)
// Case-insensitive filtering:
create.selectFrom(BOOK)
      .where(upper(BOOK.TITLE).eq("ANIMAL FARM")).fetch();

// Case-insensitive ordering:
create.selectFrom(AUTHOR)
      .orderBy(upper(AUTHOR.FIRST_NAME), upper(AUTHOR.LAST_NAME))
      .fetch();
 

4.7.8. General functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

There are a variety of general functions supported by jOOQ. As discussed in the chapter about SQL dialects functions are mostly emulated in your database, in case they are not natively supported.

 

4.7.8.1. COALESCE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COALESCE() function produces the first non-NULL value from the variadic list of arguments.

SELECT coalesce(null, null, 1);
create.select(coalesce(null, null, 1)).fetch();

The result being

+----------+
| coalesce |
+----------+
|        1 |
+----------+

Dialect support

This example using jOOQ:

coalesce(null, null, 1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
coalesce(NULL, NULL, 1)

-- DERBY
coalesce(?, ?, 1)

-- INFORMIX
nvl(
  nvl(
    NULL,
    NULL
  ),
  1
)
 

4.7.8.2. DECODE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some SQL dialects, including Db2, H2, Oracle know a more succinct, but maybe less readable DECODE() function with a variable number of arguments. This function works like a NULL safe CASE expression. jOOQ supports the DECODE() function and emulates it using CASE expressions in all dialects that do not have native support:

SELECT
  -- Oracle:
  DECODE(FIRST_NAME, 'Paulo', 'brazilian',
                     'George', 'english',
                     'unknown'),
  -- Other SQL dialects
  CASE
    WHEN FIRST_NAME IS NOT DISTINCT FROM 'Paulo'  THEN 'brazilian'
    WHEN FIRST_NAME IS NOT DISTINCT FROM 'George' THEN 'english'
    ELSE 'unknown'
  END
FROM AUTHOR




// Use the Oracle-style DECODE() function with jOOQ.
// Note, that you will not be able to rely on type-safety
decode(
  AUTHOR.FIRST_NAME,
  "Paulo", "brazilian",
  "George", "english",
  "unknown"
);

See the DISTINCT predicate for details about the NULL safe semantics.

Dialect support

This example using jOOQ:

decode(AUTHOR.FIRST_NAME, "Paulo", "BR", "George", "EN", "unknown")

Translates to the following dialect specific expressions:

-- ASE, SQLDATAWAREHOUSE
CASE
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    INTERSECT
    SELECT 'Paulo' x
  ) THEN 'BR'
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    INTERSECT
    SELECT 'George' x
  ) THEN 'EN'
  ELSE 'unknown'
END

-- AURORA_MYSQL, MYSQL
CASE
  WHEN (AUTHOR.FIRST_NAME <=> 'Paulo') THEN 'BR'
  WHEN (AUTHOR.FIRST_NAME <=> 'George') THEN 'EN'
  ELSE 'unknown'
END

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, FIREBIRD, HSQLDB, POSTGRES, SNOWFLAKE, SQLSERVER, TRINO, YUGABYTEDB
CASE
  WHEN AUTHOR.FIRST_NAME IS NOT DISTINCT FROM 'Paulo' THEN 'BR'
  WHEN AUTHOR.FIRST_NAME IS NOT DISTINCT FROM 'George' THEN 'EN'
  ELSE 'unknown'
END

-- DB2, EXASOL, H2, INFORMIX, MEMSQL, ORACLE, TERADATA, VERTICA
decode(
  AUTHOR.FIRST_NAME,
  'Paulo',
  'BR',
  'George',
  'EN',
  'unknown'
)

-- DERBY
CASE
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    FROM SYSIBM.SYSDUMMY1
    INTERSECT
    SELECT 'Paulo' x
    FROM SYSIBM.SYSDUMMY1
  ) THEN 'BR'
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    FROM SYSIBM.SYSDUMMY1
    INTERSECT
    SELECT 'George' x
    FROM SYSIBM.SYSDUMMY1
  ) THEN 'EN'
  ELSE 'unknown'
END

-- HANA
map(
  AUTHOR.FIRST_NAME,
  'Paulo',
  'BR',
  'George',
  'EN',
  'unknown'
)

-- MARIADB
decode_oracle(
  AUTHOR.FIRST_NAME,
  'Paulo',
  'BR',
  'George',
  'EN',
  'unknown'
)

-- REDSHIFT
CASE
  WHEN NOT (AUTHOR.FIRST_NAME IS DISTINCT FROM 'Paulo') THEN 'BR'
  WHEN NOT (AUTHOR.FIRST_NAME IS DISTINCT FROM 'George') THEN 'EN'
  ELSE 'unknown'
END

-- SQLITE
CASE
  WHEN (AUTHOR.FIRST_NAME IS 'Paulo') THEN 'BR'
  WHEN (AUTHOR.FIRST_NAME IS 'George') THEN 'EN'
  ELSE 'unknown'
END

-- SYBASE
CASE
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    FROM SYS.DUMMY
    INTERSECT
    SELECT 'Paulo' x
    FROM SYS.DUMMY
  ) THEN 'BR'
  WHEN EXISTS (
    SELECT AUTHOR.FIRST_NAME x
    FROM SYS.DUMMY
    INTERSECT
    SELECT 'George' x
    FROM SYS.DUMMY
  ) THEN 'EN'
  ELSE 'unknown'
END

-- ACCESS
/* UNSUPPORTED */
 

4.7.8.3. NULLIF

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The NULLIF() function produces a NULL value if both its arguments are equal, otherwise it produces the first argument.

SELECT nullif(1, 1), nullif(1, 2);
create.select(nullif(1, 1), nullif(1, 2)).fetch();

The result being

+--------+--------+
| nullif | nullif |
+--------+--------+
|        |      1 |
+--------+--------+

Dialect support

This example using jOOQ:

nullif(1, 2)

Translates to the following dialect specific expressions:

-- ACCESS
iif(1 = 2, NULL, 1)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
nullif(1, 2)
 

4.7.8.4. NVL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The NVL() function (or also the ISNULL() or IFNULL() functions) produces the first argument if it is NOT NULL, otherwise the second argument. It is a special case of the COALESCE function, which takes any number of arguments.

SELECT nvl(null, 1);
create.select(nvl(null, 1)).fetch();

The result being

+-----+
| nvl |
+-----+
|   1 |
+-----+

Dialect support

This example using jOOQ:

nvl(null, 1)

Translates to the following dialect specific expressions:

-- ACCESS
iif(NULL IS NULL, 1, NULL)

-- ASE, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, HANA, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, 
-- SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
coalesce(
  NULL,
  1
)

-- AURORA_MYSQL, BIGQUERY, MARIADB, MEMSQL, MYSQL, SQLITE
ifnull(
  NULL,
  1
)

-- DB2, H2, HSQLDB, INFORMIX, ORACLE
nvl(
  NULL,
  1
)

-- DERBY
coalesce(
  ?,
  1
)
 

4.7.8.5. NVL2

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The NVL2() function checks if the first argument is NOT NULL to produce the second argument, or the third argument otherwise. It works in a similar way as the CASE expression

SELECT
  nvl2(1,    2, 3),
  nvl2(null, 2, 3);
create.select(
  nvl2(val(1)             , 2, 3),
  nvl2(val((Integer) null), 2, 3)).fetch();

The result being

+------+------+
| nvl2 | nvl2 |
+------+------+
|    2 |    3 |
+------+------+

Dialect support

This example using jOOQ:

nvl2(val(1), 2, 3)

Translates to the following dialect specific expressions:

-- ACCESS, SQLSERVER
iif(1 IS NOT NULL, 2, 3)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, FIREBIRD, HANA, MEMSQL, MYSQL, POSTGRES, 
-- SQLDATAWAREHOUSE, SQLITE, SYBASE, TRINO, YUGABYTEDB
CASE
  WHEN 1 IS NOT NULL THEN 2
  ELSE 3
END

-- DB2, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, ORACLE, REDSHIFT, SNOWFLAKE, TERADATA, VERTICA
nvl2(1, 2, 3)
 

4.7.9. Numeric functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In addition to the arithmetic expressions discussed previously, jOOQ also supports a variety of numeric functions. As discussed in the chapter about SQL dialects numeric functions (as any function type) are mostly emulated in your database, in case they are not natively supported.

 

4.7.9.1. ABS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ABS() function produces the absolute value of a numeric value.

SELECT abs(-5), abs(0), abs(3);
create.select(abs(-5), abs(0), abs(3)).fetch();

The result being

+-----+-----+-----+
| abs | abs | abs |
+-----+-----+-----+
|   5 |   0 |   3 |
+-----+-----+-----+

Dialect support

This example using jOOQ:

abs(3)

Translates to the following dialect specific expressions:

-- All dialects
abs(3)
 

4.7.9.2. ACOS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ACOS() function calculates the arc cosine of a numeric value.

SELECT acos(0);
create.select(acos(0)).fetch();

The result being

+------------+
|       acos |
+------------+
| 1.57079633 |
+------------+

Dialect support

This example using jOOQ:

acos(0)

Translates to the following dialect specific expressions:

-- ACCESS
(atn((-0 / sqr(((-0 * 0) + 1)))) + (2 * atn(1)))

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- VERTICA, YUGABYTEDB
acos(0)

-- SNOWFLAKE, TRINO
/* UNSUPPORTED */
 

4.7.9.3. ASIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ASIN() function calculates the arc sine of a numeric value.

SELECT asin(1);
create.select(asin(1)).fetch();

The result being

+------------+
|       asin |
+------------+
| 1.57079633 |
+------------+

Dialect support

This example using jOOQ:

asin(1)

Translates to the following dialect specific expressions:

-- ACCESS
atn((1 / sqr(((-1 * 1) + 1))))

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- VERTICA, YUGABYTEDB
asin(1)

-- SNOWFLAKE, TRINO
/* UNSUPPORTED */
 

4.7.9.4. ATAN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ATAN() function calculates the arc tangent of a numeric value.

SELECT atan(1);
create.select(atan(1)).fetch();

The result being

+-------------+
|        atan |
+-------------+
| 0.785398163 |
+-------------+

Dialect support

This example using jOOQ:

atan(1)

Translates to the following dialect specific expressions:

-- ACCESS
atn(1)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- VERTICA, YUGABYTEDB
atan(1)

-- SNOWFLAKE, TRINO
/* UNSUPPORTED */
 

4.7.9.5. ATAN2

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ATAN2() function calculates the ATAN2 of a numeric value.

SELECT atan2(1, 1);
create.select(atan2(1, 1)).fetch();

The result being

+---------------+
|         atan2 |
+---------------+
| 0.78539816339 |
+---------------+

Dialect support

This example using jOOQ:

atan2(1, 1)

Translates to the following dialect specific expressions:

-- ASE, SQLDATAWAREHOUSE, SQLSERVER
atn2(1, 1)

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, VERTICA, YUGABYTEDB
atan2(1, 1)

-- ACCESS, TRINO
/* UNSUPPORTED */
 

4.7.9.6. CEIL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CEIL() function rounds a numeric value to its nearest higher integer.

SELECT
  ceil(1.7),
  ceil(-1.7);
create.select(
  ceil(1.7),
  ceil(-1.7)).fetch();

The result being

+-------+-------+
| floor | floor |
+-------+-------+
|     2 |    -1 |
+-------+-------+

Dialect support

This example using jOOQ:

ceil(1.7)

Translates to the following dialect specific expressions:

-- ACCESS
(CLNG(1.7E0) - (1.7E0 - clng(1.7E0) > 0))

-- ASE, SQLDATAWAREHOUSE, SQLSERVER
ceiling(1.7E0)

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
ceil(1.7E0)

-- COCKROACHDB
ceil(CAST(1.7E0 AS double precision))

-- H2
ceiling(CAST(1.7E0 AS double))
 

4.7.9.7. COS

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COS() function calculates the cosine of a numeric value.

SELECT cos(3.14159265359);
create.select(cos(3.14159265359)).fetch();

The result being

+-----+
| cos |
+-----+
|  -1 |
+-----+

Dialect support

This example using jOOQ:

cos(3.14159265359)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
cos(3.14159265359E0)

-- COCKROACHDB
cos(CAST(3.14159265359E0 AS double precision))

-- H2
cos(CAST(3.14159265359E0 AS double))
 

4.7.9.8. COSH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COSH() function calculates the hyperbolic cosine of a numeric value.

SELECT cosh(1);
create.select(cosh(1)).fetch();

The result being

+---------------+
|          cosh |
+---------------+
| 1.54308063482 |
+---------------+

Dialect support

This example using jOOQ:

cosh(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
((exp((1 * 2)) + 1) / (exp(1) * 2))

-- BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, INFORMIX, ORACLE, SNOWFLAKE, SQLITE, TERADATA, TRINO
cosh(1)

-- COCKROACHDB
((exp(CAST((1 * 2) AS numeric)) + 1) / (exp(CAST(1 AS numeric)) * 2))
 

4.7.9.9. COT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COT() function calculates the cotangent of a numeric value.

SELECT cot(1.5707963268);
create.select(cot(1.5707963268)).fetch();

The result being

+-----+
| cot |
+-----+
|   0 |
+-----+

Dialect support

This example using jOOQ:

cot(1.5707963268)

Translates to the following dialect specific expressions:

-- ACCESS, BIGQUERY, INFORMIX, ORACLE, SQLITE, TERADATA, TRINO
(cos(1.5707963268E0) / sin(1.5707963268E0))

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, 
-- POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
cot(1.5707963268E0)

-- COCKROACHDB
cot(CAST(1.5707963268E0 AS double precision))

-- H2
cot(CAST(1.5707963268E0 AS double))
 

4.7.9.10. COTH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COTH() function calculates the hyperbolic cotangent of a numeric value.

SELECT coth(1);
create.select(coth(1)).fetch();

The result being

+--------------+
|         coth |
+--------------+
| 1.3130352855 |
+--------------+

Dialect support

This example using jOOQ:

coth(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
((exp((1 * 2)) + 1) / (exp((1 * 2)) - 1))

-- COCKROACHDB
((exp(CAST((1 * 2) AS numeric)) + 1) / (exp(CAST((1 * 2) AS numeric)) - 1))
 

4.7.9.11. DEG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DEG() function calculates the degrees from a radian value (see also RAD).

SELECT deg(3.14159265359);
create.select(deg(3.14159265359)).fetch();

The result being

+-----+
| deg |
+-----+
| 180 |
+-----+

Dialect support

This example using jOOQ:

deg(3.14159265359)

Translates to the following dialect specific expressions:

-- ACCESS
((3.14159265359E0 * 180) / 3.141592653589793)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, DB2, DERBY, DUCKDB, EXASOL, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, POSTGRES, 
-- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
degrees(3.14159265359E0)

-- BIGQUERY
((CAST(3.14159265359E0 AS decimal) * 180) / acos(-1))

-- COCKROACHDB
degrees(CAST(3.14159265359E0 AS double precision))

-- FIREBIRD
((CAST(3.14159265359E0 AS numeric) * 180) / pi())

-- H2
degrees(CAST(3.14159265359E0 AS double))

-- HANA
((CAST(3.14159265359E0 AS numeric) * 180) / acos(-1))

-- ORACLE
((CAST(3.14159265359E0 AS number) * 180) / acos(-1))
 

4.7.9.12. E

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The E() function produces the Euler constant e, which is around 2.71828182846

SELECT e();
create.select(e()).fetch();

The result being

+---------------+
| exp           |
+---------------+
| 2.71828182846 |
+---------------+

Dialect support

This example using jOOQ:

e()

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- VERTICA, YUGABYTEDB
exp(1)

-- COCKROACHDB
exp(CAST(1 AS numeric))

-- TRINO
e()
 

4.7.9.13. EXP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The EXP() function calculates e^x

SELECT exp(1);
create.select(exp(1)).fetch();

The result being

+---------------+
| exp           |
+---------------+
| 2.71828182846 |
+---------------+

Dialect support

This example using jOOQ:

exp(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
exp(1)

-- COCKROACHDB
exp(CAST(1 AS numeric))
 

4.7.9.14. FLOOR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The FLOOR() function rounds a numeric value to its nearest lower integer.

SELECT
  floor(1.7),
  floor(-1.7);
create.select(
  floor(1.7),
  floor(-1.7)).fetch();

The result being

+-------+-------+
| floor | floor |
+-------+-------+
|     1 |    -2 |
+-------+-------+

Dialect support

This example using jOOQ:

floor(1.7)

Translates to the following dialect specific expressions:

-- ACCESS
(cdec(1.7E0) - (1.7E0 < cdec(1.7E0)))

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, 
-- MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
floor(1.7E0)

-- COCKROACHDB
floor(CAST(1.7E0 AS double precision))

-- H2
floor(CAST(1.7E0 AS double))
 

4.7.9.15. GREATEST

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The GREATEST() function produces the greatest value among all the arguments.

SELECT greatest(2, 3);
create.select(greatest(2, 3)).fetch();

The result being

+----------+
| greatest |
+----------+
|        3 |
+----------+

Dialect support

This example using jOOQ:

greatest(2, 3)

Translates to the following dialect specific expressions:

-- ACCESS
SWITCH(2 > 3, 2, TRUE, 3)

-- ASE, DERBY, INFORMIX, SQLDATAWAREHOUSE, SYBASE
CASE
  WHEN 2 > 3 THEN 2
  ELSE 3
END

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, 
-- ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLSERVER, TERADATA, TRINO, VERTICA, YUGABYTEDB
greatest(2, 3)

-- FIREBIRD
maxvalue(2, 3)

-- SQLITE
max(2, 3)
 

4.7.9.16. LEAST

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LEAST() function produces the least value among all the arguments.

SELECT least(2, 3);
create.select(least(2, 3)).fetch();

The result being

+-------+
| least |
+-------+
|     2 |
+-------+

Dialect support

This example using jOOQ:

least(2, 3)

Translates to the following dialect specific expressions:

-- ACCESS
SWITCH(2 < 3, 2, TRUE, 3)

-- ASE, DERBY, INFORMIX, SQLDATAWAREHOUSE, SYBASE
CASE
  WHEN 2 < 3 THEN 2
  ELSE 3
END

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, 
-- ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLSERVER, TERADATA, TRINO, VERTICA, YUGABYTEDB
least(2, 3)

-- FIREBIRD
minvalue(2, 3)

-- SQLITE
min(2, 3)
 

4.7.9.17. LN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LN() function calculates the natural logarithm of a numeric value.

SELECT ln(1);
create.select(ln(1)).fetch();

The result being

+----+
| ln |
+----+
|  0 |
+----+

Dialect support

This example using jOOQ:

ln(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, SQLDATAWAREHOUSE, SQLSERVER
log(1)

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, MEMSQL, 
-- MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
ln(1)

-- COCKROACHDB
ln(CAST(1 AS numeric))

-- INFORMIX
logn(1)
 

4.7.9.18. LOG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LOG() function calculates the logarithm of a numeric value, given a base.

SELECT log(8, 2);
create.select(log(8, 2)).fetch();

The result being

+-----+
| log |
+-----+
|   3 |
+-----+

Dialect support

This example using jOOQ:

log(8, 2)

Translates to the following dialect specific expressions:

-- ACCESS, ASE
(log(8) / log(2))

-- AURORA_MYSQL, AURORA_POSTGRES, EXASOL, FIREBIRD, H2, HANA, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TRINO, VERTICA, YUGABYTEDB
log(2, 8)

-- BIGQUERY, SQLDATAWAREHOUSE, SQLSERVER
log(8, 2)

-- COCKROACHDB
(ln(CAST(8 AS numeric)) / ln(CAST(2 AS numeric)))

-- DB2, DERBY, DUCKDB, HSQLDB, SQLITE, SYBASE, TERADATA
(ln(8) / ln(2))

-- INFORMIX
(logn(8) / logn(2))
 

4.7.9.19. NEG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The NEG() function produces the negation of its argument.

SELECT neg(2);
create.select(neg(2)).fetch();

The result being

+-----+
| neg |
+-----+
|  -2 |
+-----+

Dialect support

This example using jOOQ:

neg(val(2))

Translates to the following dialect specific expressions:

-- All dialects
-2
 

4.7.9.20. PI

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The PI() function produces the pi constant π, which is around 3.14159265359

SELECT pi();
create.select(pi()).fetch();

The result being

+---------------+
| pi            |
+---------------+
| 3.14159265359 |
+---------------+

Dialect support

This example using jOOQ:

pi()

Translates to the following dialect specific expressions:

-- ACCESS
3.141592653589793

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, 
-- POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TRINO, VERTICA, YUGABYTEDB
pi()

-- BIGQUERY, DB2, HANA, INFORMIX, ORACLE, TERADATA
acos(-1)
 

4.7.9.21. POWER

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The POWER() function calculates the power of two numbers.

SELECT power(2, 3);
create.select(power(2, 3)).fetch();

The result being

+-------+
| power |
+-------+
|     8 |
+-------+

Dialect support

This example using jOOQ:

power(2, 3)

Translates to the following dialect specific expressions:

-- ACCESS
(2 ^ 3)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
power(2, 3)

-- DERBY
exp((ln(2) * 3))

-- SNOWFLAKE
/* UNSUPPORTED */
 

4.7.9.22. RAD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RAD() function calculates the radian value from degrees (see also DEG).

SELECT rad(180);
create.select(rad(180)).fetch();

The result being

+---------------+
|           rad |
+---------------+
| 3.14159265359 |
+---------------+

Dialect support

This example using jOOQ:

rad(180)

Translates to the following dialect specific expressions:

-- ACCESS
((cdec(180) * 3.141592653589793) / 180)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
radians(180)

-- BIGQUERY
((CAST(180 AS decimal) * acos(-1)) / 180)

-- FIREBIRD
((CAST(180 AS numeric) * pi()) / 180)

-- HANA
((CAST(180 AS numeric) * acos(-1)) / 180)

-- ORACLE
((CAST(180 AS number) * acos(-1)) / 180)
 

4.7.9.23. RAND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RAND() function produces a random number.

SELECT rand();
create.select(rand()).fetch();

The result being

+------+
| rand |
+------+
|    4 | chosen by fair dice roll
+------+

Dialect support

This example using jOOQ:

rand()

Translates to the following dialect specific expressions:

-- ACCESS
rnd

-- ASE, AURORA_MYSQL, BIGQUERY, DB2, FIREBIRD, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, SQLDATAWAREHOUSE, SQLSERVER, 
-- SYBASE, TRINO
rand()

-- AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, POSTGRES, REDSHIFT, SQLITE, VERTICA, YUGABYTEDB
random()

-- ORACLE
DBMS_RANDOM.RANDOM

-- TERADATA
(CAST((random(-2147483648, 2147483647) + 2147483648) AS NUMERIC(38, 19)) / 4294967295)

-- INFORMIX, SNOWFLAKE
/* UNSUPPORTED */
 

4.7.9.24. ROUND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ROUND() function rounds a numeric value to its nearest integer, or optionally, to the nearest decimal precision.

SELECT
  round(1.7),
  round(-1.7);
create.select(
  round(1.7),
  round(-1.7)).fetch();

The result being

+-------+-------+
| round | round |
+-------+-------+
|     2 |    -2 |
+-------+-------+

Dialect support

This example using jOOQ:

round(1.7)

Translates to the following dialect specific expressions:

-- ACCESS, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, 
-- MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, TRINO, VERTICA, YUGABYTEDB
round(1.7E0)

-- ASE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE
round(1.7E0, 0)

-- COCKROACHDB
round(CAST(CAST(1.7E0 AS double precision) AS numeric))

-- DERBY
CASE
  WHEN (1.7E0 - floor(1.7E0)) < 5E-1 THEN floor(1.7E0)
  ELSE ceil(1.7E0)
END

-- H2
round(CAST(1.7E0 AS double))
 

4.7.9.25. SIGN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SIGN() function produces the sign of a numeric value, being any value of -1, 0, 1

SELECT sign(-5), sign(0), sign(3);
create.select(sign(-5), sign(0), sign(3)).fetch();

The result being

+------+------+------+
| sign | sign | sign |
+------+------+------+
|   -1 |    0 |    1 |
+------+------+------+

Dialect support

This example using jOOQ:

sign(3)

Translates to the following dialect specific expressions:

-- ACCESS
sgn(3)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
sign(3)

-- SQLITE
CASE
  WHEN 3 > 0 THEN 1
  WHEN 3 < 0 THEN -1
  WHEN 3 = 0 THEN 0
END
 

4.7.9.26. SIN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SIN() function calculates the sine of a numeric value.

SELECT sin(3.14159265359);
create.select(sin(3.14159265359)).fetch();

The result being

+-----+
| sin |
+-----+
|   0 |
+-----+

Dialect support

This example using jOOQ:

sin(3.14159265359)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, 
-- TRINO, VERTICA, YUGABYTEDB
sin(3.14159265359E0)

-- COCKROACHDB
sin(CAST(3.14159265359E0 AS double precision))

-- H2
sin(CAST(3.14159265359E0 AS double))
 

4.7.9.27. SINH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SINH() function calculates the hyperbolic sine of a numeric value.

SELECT sinh(1);
create.select(sinh(1)).fetch();

The result being

+---------------+
|          sinh |
+---------------+
| 1.17520119364 |
+---------------+

Dialect support

This example using jOOQ:

sinh(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO, VERTICA, YUGABYTEDB
((exp((1 * 2)) - 1) / (exp(1) * 2))

-- BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, INFORMIX, ORACLE, SNOWFLAKE, SQLITE, TERADATA
sinh(1)

-- COCKROACHDB
((exp(CAST((1 * 2) AS numeric)) - 1) / (exp(CAST(1 AS numeric)) * 2))
 

4.7.9.28. SQRT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQRT() function calculates the square root of a numeric value.

SELECT sqrt(4);
create.select(sqrt(4)).fetch();

The result being

+------+
| sqrt |
+------+
|    2 |
+------+

Dialect support

This example using jOOQ:

sqrt(4)

Translates to the following dialect specific expressions:

-- ACCESS
sqr(4)

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
sqrt(4)

-- COCKROACHDB
sqrt(CAST(4 AS numeric))
 

4.7.9.29. TAN

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The TAN() function calculates the tangent of a numeric value.

SELECT tan(3.14159265359);
create.select(tan(3.14159265359)).fetch();

The result being

+-----+
| tan |
+-----+
|   0 |
+-----+

Dialect support

This example using jOOQ:

tan(3.14159265359)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, 
-- YUGABYTEDB
tan(3.14159265359E0)

-- COCKROACHDB
tan(CAST(3.14159265359E0 AS double precision))

-- H2
tan(CAST(3.14159265359E0 AS double))

-- SNOWFLAKE
/* UNSUPPORTED */
 

4.7.9.30. TANH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The TANH() function calculates the hyperbolic tangent of a numeric value.

SELECT tanh(1);
create.select(tanh(1)).fetch();

The result being

+---------------+
|          tanh |
+---------------+
| 0.76159415595 |
+---------------+

Dialect support

This example using jOOQ:

tanh(1)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
((exp((1 * 2)) - 1) / (exp((1 * 2)) + 1))

-- BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, INFORMIX, ORACLE, SQLITE, TERADATA, TRINO
tanh(1)

-- COCKROACHDB
((exp(CAST((1 * 2) AS numeric)) - 1) / (exp(CAST((1 * 2) AS numeric)) + 1))

-- SNOWFLAKE
/* UNSUPPORTED */
 

4.7.9.31. TRUNC

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The TRUNC() function rounds a numeric value to its nearest integer (or optionally, to a specific decimal precision) that is closer to zero.

SELECT
  trunc(1.7),
  trunc(-1.7);
create.select(
  trunc(1.7),
  trunc(-1.7)).fetch();

The result being

+-------+-------+
| trunc | trunc |
+-------+-------+
|     1 |    -1 |
+-------+-------+

Dialect support

This example using jOOQ:

trunc(1.7)

Translates to the following dialect specific expressions:

-- ASE
CASE
  WHEN sign(1.7E0) >= 0 THEN (floor((1.7E0 * 1)) / 1)
  ELSE (ceiling((1.7E0 * 1)) / 1)
END

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
truncate(1.7E0, 0)

-- AURORA_POSTGRES, POSTGRES
CAST(trunc(
  CAST(1.7E0 AS numeric),
  0
) AS double precision)

-- DB2, FIREBIRD, HSQLDB, INFORMIX, ORACLE, TERADATA, VERTICA
trunc(1.7E0, 0)

-- DERBY
CASE
  WHEN sign(1.7E0) >= 0 THEN (floor((1.7E0 * 1)) / 1)
  ELSE (ceil((1.7E0 * 1)) / 1)
END

-- H2
truncate(CAST(1.7E0 AS double), 0)

-- HANA
round(1.7E0, 0, round_down)

-- SQLDATAWAREHOUSE, SQLSERVER
round(1.7E0, 0, 1)

-- SYBASE
truncnum(1.7E0, 0)

-- ACCESS, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, REDSHIFT, SNOWFLAKE, SQLITE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.10. Bitwise functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Most databases only support a few bitwise operations, while others ship with the full set of operators. jOOQ's API includes most bitwise operations as listed below. In order to avoid ambiguities with conditional operators, most bitwise functions are prefixed with "bit"

 

4.7.10.1. BIT_AND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_AND() function produces the bitwise AND operation.

SELECT bit_and(5, 4);
create.select(bitAnd(5, 4)).fetch();

The result being

+---------+
| bit_and |
+---------+
|       4 |
+---------+

Dialect support

This example using jOOQ:

bitAnd(5, 4)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
(5 & 4)

-- DB2, H2, HANA, HSQLDB, INFORMIX, ORACLE, SNOWFLAKE, TERADATA
bitand(5, 4)

-- EXASOL
bit_and(5, 4)

-- FIREBIRD
bin_and(5, 4)

-- TRINO
bitwise_and(5, 4)

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.2. BIT_COUNT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_COUNT() function counts the number of bits in a value.

SELECT bit_count(5);
create.select(bitCount(5)).fetch();

The result being

+-----------+
| bit_count |
+-----------+
|         2 |
+-----------+

Dialect support

This example using jOOQ:

bitCount((byte) 5)

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, DUCKDB, MARIADB, MEMSQL, MYSQL, SQLSERVER
bit_count(5)

-- AURORA_POSTGRES, POSTGRES, REDSHIFT, SQLITE, VERTICA, YUGABYTEDB
CAST(((5 & 1) + ((5 & 2) >> 1) + ((5 & 4) >> 2) + ((5 & 8) >> 3) + ((5 & 16) >> 4) + ((5 & 32) >> 5) + ((5 & 64) >> 6) + ((5 & -128) >> 7)) AS int)

-- BIGQUERY
CAST(((5 & 1) + ((5 & 2) >> 1) + ((5 & 4) >> 2) + ((5 & 8) >> 3) + ((5 & 16) >> 4) + ((5 & 32) >> 5) + ((5 & 64) >> 6) + ((5 & -128) >> 7)) AS int64)

-- COCKROACHDB
CAST(((5 & 1) + ((5 & 2) >> 1) + ((5 & 4) >> 2) + ((5 & 8) >> 3) + ((5 & 16) >> 4) + ((5 & 32) >> 5) + ((5 & 64) >> 6) + ((5 & -128) >> 7)) AS int4)

-- FIREBIRD
CAST((bin_and(5, 1) + bin_shr(
  bin_and(5, 2),
  1
) + bin_shr(
  bin_and(5, 4),
  2
) + bin_shr(
  bin_and(5, 8),
  3
) + bin_shr(
  bin_and(5, 16),
  4
) + bin_shr(
  bin_and(5, 32),
  5
) + bin_shr(
  bin_and(5, 64),
  6
) + bin_shr(
  bin_and(5, -128),
  7
)) AS integer)

-- H2, HSQLDB
CAST((bitand(5, 1) + (bitand(5, 2) / 2) + (bitand(5, 4) / 4) + (bitand(5, 8) / 8) + (bitand(5, 16) / 16) + (bitand(5, 32) / 32) + (bitand(5, 64) / 64) + (bitand(5, -128) / -128)) AS int)

-- HANA
bitcount(5)

-- INFORMIX
CAST((bitand(5, 1) + (bitand(5, 2) / 2) + (bitand(5, 4) / 4) + (bitand(5, 8) / 8) + (bitand(5, 16) / 16) + (bitand(5, 32) / 32) + (bitand(5, 64) / 64) + (bitand(5, -128) / -128)) AS integer)

-- ORACLE
CAST((bitand(5, 1) + (bitand(5, 2) / 2) + (bitand(5, 4) / 4) + (bitand(5, 8) / 8) + (bitand(5, 16) / 16) + (bitand(5, 32) / 32) + (bitand(5, 64) / 64) + (bitand(5, -128) / -128)) AS number(10))

-- SNOWFLAKE
CAST((bitand(5, 1) + bitshiftright(
  bitand(5, 2),
  1
) + bitshiftright(
  bitand(5, 4),
  2
) + bitshiftright(
  bitand(5, 8),
  3
) + bitshiftright(
  bitand(5, 16),
  4
) + bitshiftright(
  bitand(5, 32),
  5
) + bitshiftright(
  bitand(5, 64),
  6
) + bitshiftright(
  bitand(5, -128),
  7
)) AS number(10))

-- SQLDATAWAREHOUSE, SYBASE
CAST(((5 & 1) + ((5 & 2) / 2) + ((5 & 4) / 4) + ((5 & 8) / 8) + ((5 & 16) / 16) + ((5 & 32) / 32) + ((5 & 64) / 64) + ((5 & -128) / -128)) AS int)

-- TERADATA
countset(5, 1)

-- TRINO
CAST((bitwise_and(5, 1) + bitwise_right_shift(
  bitwise_and(5, 2),
  1
) + bitwise_right_shift(
  bitwise_and(5, 4),
  2
) + bitwise_right_shift(
  bitwise_and(5, 8),
  3
) + bitwise_right_shift(
  bitwise_and(5, 16),
  4
) + bitwise_right_shift(
  bitwise_and(5, 32),
  5
) + bitwise_right_shift(
  bitwise_and(5, 64),
  6
) + bitwise_right_shift(
  bitwise_and(5, -128),
  7
)) AS int)

-- ACCESS, ASE, DB2, DERBY, EXASOL
/* UNSUPPORTED */
 

4.7.10.3. BIT_NAND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_NAND() function produces the bitwise NAND operation.

SELECT bit_nand(5, 4);
create.select(bitNand(5, 4)).fetch();

The result being

+----------+
| bit_nand |
+----------+
|       -5 |
+----------+

Dialect support

This example using jOOQ:

bitNand(5, 4)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
~((5 & 4))

-- DB2, H2, HANA, INFORMIX, SNOWFLAKE, TERADATA
bitnot(bitand(5, 4))

-- EXASOL
bit_not(bit_and(5, 4))

-- FIREBIRD
bin_not(bin_and(5, 4))

-- HSQLDB, ORACLE
((0 - bitand(5, 4)) - 1)

-- TRINO
bitwise_not(bitwise_and(5, 4))

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.4. BIT_NOR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_NOR() function produces the bitwise NOR operation.

SELECT bit_nor(5, 2);
create.select(bitNor(5, 2)).fetch();

The result being

+---------+
| bit_nor |
+---------+
|      -8 |
+---------+

Dialect support

This example using jOOQ:

bitNor(5, 2)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
~((5 | 2))

-- DB2, H2, HANA, INFORMIX, SNOWFLAKE, TERADATA
bitnot(bitor(5, 2))

-- EXASOL
bit_not(bit_or(5, 2))

-- FIREBIRD
bin_not(bin_or(5, 2))

-- HSQLDB
((0 - bitor(5, 2)) - 1)

-- ORACLE
((0 - ((5 + 2) - bitand(5, 2))) - 1)

-- TRINO
bitwise_not(bitwise_or(5, 2))

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.5. BIT_NOT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_NOT() function inverts the bits in a number, producing the 2's complement of a signed number.

SELECT bit_not(5);
create.select(bitNot(5)).fetch();

The result being

+---------+
| bit_not |
+---------+
|      -6 |
+---------+

Dialect support

This example using jOOQ:

bitNot(5)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
~5

-- DB2, H2, HANA, INFORMIX, SNOWFLAKE, TERADATA
bitnot(5)

-- EXASOL
bit_not(5)

-- FIREBIRD
bin_not(5)

-- HSQLDB, ORACLE
((0 - 5) - 1)

-- TRINO
bitwise_not(5)

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.6. BIT_OR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_OR() function produces the bitwise OR operation.

SELECT bit_or(5, 2);
create.select(bitOr(5, 2)).fetch();

The result being

+--------+
| bit_or |
+--------+
|      7 |
+--------+

Dialect support

This example using jOOQ:

bitOr(5, 2)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, VERTICA, YUGABYTEDB
(5 | 2)

-- DB2, H2, HANA, HSQLDB, INFORMIX, SNOWFLAKE, TERADATA
bitor(5, 2)

-- EXASOL
bit_or(5, 2)

-- FIREBIRD
bin_or(5, 2)

-- ORACLE
((5 + 2) - bitand(5, 2))

-- TRINO
bitwise_or(5, 2)

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.7. BIT_XNOR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_XNOR() function produces the bitwise XNOR (exclusive NOR) operation.

SELECT bit_xnor(5, 3);
create.select(bitXNor(5, 3)).fetch();

The result being

+----------+
| bit_xnor |
+----------+
|       -7 |
+----------+

Dialect support

This example using jOOQ:

bitXNor(5, 3)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, BIGQUERY, MARIADB, MEMSQL, MYSQL, SQLDATAWAREHOUSE, SQLSERVER, SYBASE
~((5 ^ 3))

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, REDSHIFT, VERTICA, YUGABYTEDB
~((5 # 3))

-- DB2, HANA, INFORMIX, SNOWFLAKE, TERADATA
bitnot(bitxor(5, 3))

-- DUCKDB
~xor(5, 3)

-- EXASOL
bit_not(bit_xor(5, 3))

-- FIREBIRD
bin_not(bin_xor(5, 3))

-- H2
bitxnor(5, 3)

-- HSQLDB
((0 - bitxor(5, 3)) - 1)

-- ORACLE
((0 - bitand(
  ((0 - bitand(5, 3)) - 1),
  ((5 + 3) - bitand(5, 3))
)) - 1)

-- SQLITE
~((~((5 & 3)) & (5 | 3)))

-- TRINO
bitwise_not(bitwise_xor(5, 3))

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.8. BIT_XOR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BIT_XOR() function produces the bitwise XOR (exclusive OR) operation.

SELECT bit_xor(5, 3);
create.select(bitXor(5, 3)).fetch();

The result being

+---------+
| bit_xor |
+---------+
|       6 |
+---------+

Dialect support

This example using jOOQ:

bitXor(5, 3)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, BIGQUERY, MARIADB, MEMSQL, MYSQL, SQLDATAWAREHOUSE, SQLSERVER, SYBASE
(5 ^ 3)

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, REDSHIFT, VERTICA, YUGABYTEDB
(5 # 3)

-- DB2, H2, HANA, HSQLDB, INFORMIX, SNOWFLAKE, TERADATA
bitxor(5, 3)

-- DUCKDB
xor(5, 3)

-- EXASOL
bit_xor(5, 3)

-- FIREBIRD
bin_xor(5, 3)

-- ORACLE
bitand(
  ((0 - bitand(5, 3)) - 1),
  ((5 + 3) - bitand(5, 3))
)

-- SQLITE
(~((5 & 3)) & (5 | 3))

-- TRINO
bitwise_xor(5, 3)

-- ACCESS, DERBY
/* UNSUPPORTED */
 

4.7.10.9. SHL

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SHL() function produces the bitwise shift left operation.

SELECT shl(1, 4);
create.select(shl(1, 4)).fetch();

The result being

+-----+
| shl |
+-----+
|  16 |
+-----+

Dialect support

This example using jOOQ:

shl(1, 4)

Translates to the following dialect specific expressions:

-- ASE, HSQLDB, SQLDATAWAREHOUSE, SYBASE
(1 * CAST(power(2, 4) AS int))

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SQLITE, 
-- SQLSERVER, VERTICA, YUGABYTEDB
(1 << 4)

-- DB2, INFORMIX
(1 * CAST(power(2, 4) AS integer))

-- EXASOL
bit_lshift(1, 4)

-- FIREBIRD
bin_shl(1, 4)

-- H2
lshift(1, 4)

-- ORACLE
(1 * CAST(power(2, 4) AS number(10)))

-- SNOWFLAKE
bitshiftleft(1, 4)

-- TERADATA
shiftleft(1, 4)

-- TRINO
bitwise_left_shift(1, 4)

-- ACCESS, DERBY, HANA
/* UNSUPPORTED */
 

4.7.10.10. SHR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SR() function produces the bitwise shift right operation.

SELECT shr(16, 4);
create.select(shr(16, 4)).fetch();

The result being

+-----+
| shr |
+-----+
|   1 |
+-----+

Dialect support

This example using jOOQ:

shr(16, 4)

Translates to the following dialect specific expressions:

-- ASE, HSQLDB, SQLDATAWAREHOUSE, SYBASE
(16 / CAST(power(2, 4) AS int))

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SQLITE, 
-- SQLSERVER, VERTICA, YUGABYTEDB
(16 >> 4)

-- DB2, INFORMIX
(16 / CAST(power(2, 4) AS integer))

-- EXASOL
bit_rshift(16, 4)

-- FIREBIRD
bin_shr(16, 4)

-- H2
rshift(16, 4)

-- ORACLE
(16 / CAST(power(2, 4) AS number(10)))

-- SNOWFLAKE
bitshiftright(16, 4)

-- TERADATA
shiftright(16, 4)

-- TRINO
bitwise_right_shift(16, 4)

-- ACCESS, DERBY, HANA
/* UNSUPPORTED */
 

4.7.11. String functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

String formatting can be done efficiently in the database before returning results to your Java application. As discussed in the chapter about SQL dialects string functions (as any function type) are mostly emulated in your database, in case they are not natively supported.

 

4.7.11.1. ASCII

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ASCII() function calculates the ASCII code of a single character.

SELECT ascii('A');
create.select(ascii("A")).fetch();

The result being

+-------+
| ascii |
+-------+
|  65   |
+-------+

Dialect support

This example using jOOQ:

ascii("A")

Translates to the following dialect specific expressions:

-- ACCESS
asc('A')

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, 
-- MEMSQL, MYSQL, ORACLE, POSTGRES, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, VERTICA, YUGABYTEDB
ascii('A')

-- FIREBIRD
ascii_val('A')

-- DERBY, REDSHIFT, SQLITE, TRINO
/* UNSUPPORTED */
 

4.7.11.2. CONCAT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CONCAT() function concatenates several strings

SELECT concat('hello', ' ', 'world');
create.select(concat("hello", " ", "world")).fetch();

The result being

+-------------+
| concat      |
+-------------+
| hello world |
+-------------+

Dialect support

This example using jOOQ:

concat("hello", " ", "world")

Translates to the following dialect specific expressions:

-- ACCESS
('hello' & ' ')

-- ASE, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, ORACLE, 
-- POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB
(('hello' || ' ') || 'world')

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
concat('hello', ' ', 'world')

-- SQLDATAWAREHOUSE, SQLSERVER
(('hello' + ' ') + 'world')
 

4.7.11.3. LEFT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LEFT() function calculates the substring of a given string starting from the left end. See also SUBSTRING, RIGHT

SELECT left('hello world', 5);
create.select(left("hello world", 5)).fetch();

The result being

+-------+
| left  |
+-------+
| hello |
+-------+

Dialect support

This example using jOOQ:

left("hello world", 5)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, VERTICA, 
-- YUGABYTEDB
left('hello world', 5)

-- DERBY, ORACLE, SQLITE
substr('hello world', 1, 5)

-- TRINO
substring('hello world', 1, 5)
 

4.7.11.4. LENGTH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LENGTH() function calculates the length of a given string.

SELECT length('hello');
create.select(length("hello")).fetch();

The result being

+--------+
| length |
+--------+
|      5 |
+--------+

Dialect support

This example using jOOQ:

length("hello")

Translates to the following dialect specific expressions:

-- ACCESS, SQLDATAWAREHOUSE, SQLSERVER
len('hello')

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, POSTGRES, REDSHIFT, VERTICA, YUGABYTEDB
char_length('hello')

-- DB2, DERBY, DUCKDB, HANA, ORACLE, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO
length('hello')
 

4.7.11.5. LOWER

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LOWER() function transforms a string into lower case.

SELECT lower('HELLO');
create.select(lower("HELLO")).fetch();

The result being

+-------+
| lower |
+-------+
| hello |
+-------+

Dialect support

This example using jOOQ:

lower("HELLO")

Translates to the following dialect specific expressions:

-- ACCESS
lcase('HELLO')

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
lower('HELLO')
 

4.7.11.6. LPAD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LPAD() pads a string at the left end. See also RPAD.

SELECT lpad('hello', 10, '.');
create.select(lpad(val("hello"), 10, '.')).fetch();

The result being

+------------+
| lpad       |
+------------+
| .....hello |
+------------+

Dialect support

This example using jOOQ:

lpad(val("hello"), 10, '.')

Translates to the following dialect specific expressions:

-- ACCESS
(replace(space(10 - len('hello')), ' ', '.') & 'hello')

-- ASE
(replicate(
  '.',
  (10 - char_length('hello'))
) || 'hello')

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- POSTGRES, TERADATA, VERTICA
lpad('hello', 10, '.')

-- SQLDATAWAREHOUSE, SQLSERVER
(replicate(
  '.',
  (10 - len('hello'))
) + 'hello')

-- SQLITE
substr("replace"(hex(zeroblob(10)), '00', '.'), 1, 10 - length('hello')) || 'hello'

-- SYBASE
(repeat(
  '.',
  (10 - length('hello'))
) || 'hello')

-- BIGQUERY, DERBY, DUCKDB, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.11.7. LTRIM

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LTRIM() function trims a string from the left end, stripping it of whitespace. See also RTRIM and TRIM.

SELECT ltrim('  hello  ');
create.select(ltrim("  hello  ")).fetch();

The result being

+---------+
| ltrim   |
+---------+
| hello   |
+---------+

Dialect support

This example using jOOQ:

ltrim("  hello  ")

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
ltrim('  hello  ')

-- FIREBIRD
trim(LEADING FROM '  hello  ')
 

4.7.11.8. MD5

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The MD5() function calculates the MD5 hash of a given string.

SELECT md5('hello');
create.select(md5("hello")).fetch();

The result being

+----------------------------------+
| md5                              |
+----------------------------------+
| 5d41402abc4b2a76b9719d911017c592 |
+----------------------------------+

Dialect support

This example using jOOQ:

md5("hello")

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, SNOWFLAKE, VERTICA, 
-- YUGABYTEDB
md5('hello')

-- EXASOL
hash_md5('hello')

-- ORACLE
lower(standard_hash('hello', 'MD5'))

-- SQLDATAWAREHOUSE
lower(convert(VARCHAR(32), hashbytes('MD5', CAST('hello' AS varchar(8000))), 2))

-- SQLSERVER
lower(convert(VARCHAR(32), hashbytes('MD5', CAST('hello' AS varchar(max))), 2))

-- ACCESS, ASE, DB2, DERBY, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, REDSHIFT, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.7.11.9. MID

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The MID() function is an alias for the substring function

 

4.7.11.10. POSITION

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The POSITION() function finds the first position of a string within another string, starting with 1.

SELECT
  position('hello', 'e'),
  position('hello', 'l', 4);
create.select(
  position("hello", "e"),
  position("hello", "e", 4)).fetch();

The result being

+----------+----------+
| position | position |
+----------+----------+
|        2 |        4 |
+----------+----------+

Dialect support

This example using jOOQ:

position("hello", "e")

Translates to the following dialect specific expressions:

-- ASE, SQLDATAWAREHOUSE, SQLSERVER
charindex('e', 'hello')

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
position('e' IN 'hello')

-- BIGQUERY, INFORMIX, ORACLE, SQLITE
instr('hello', 'e')

-- DB2, DERBY
locate('e', 'hello')

-- HANA, SYBASE
locate('hello', 'e')

-- ACCESS, REDSHIFT
/* UNSUPPORTED */
 

4.7.11.11. REPEAT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The REPEAT() function repeats a string a number of times.

SELECT repeat('abc', 3);
create.select(repeat("abc", 3)).fetch();

The result being

+-----------+
| repeat    |
+-----------+
| abcabcabc |
+-----------+

Dialect support

This example using jOOQ:

repeat("abc", 3)

Translates to the following dialect specific expressions:

-- ASE, SQLDATAWAREHOUSE, SQLSERVER
replicate('abc', 3)

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MYSQL, POSTGRES, 
-- SNOWFLAKE, SYBASE, VERTICA, YUGABYTEDB
repeat('abc', 3)

-- FIREBIRD, MEMSQL
rpad(
  'abc',
  (char_length('abc') * 3),
  'abc'
)

-- HANA, ORACLE, TERADATA, TRINO
rpad(
  'abc',
  (length('abc') * 3),
  'abc'
)

-- SQLITE
"replace"(hex(zeroblob(3)), '00', 'abc')

-- ACCESS, DERBY, INFORMIX, REDSHIFT
/* UNSUPPORTED */
 

4.7.11.12. REPLACE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The REPLACE() function replaces a substring inside of a string by another string.

SELECT replace('hello world', 'llo', 'y');
create.select(replace(val("hello world"), "llo", "y")).fetch();

The result being

+-----------+
| replace   |
+-----------+
| hey world |
+-----------+

Dialect support

This example using jOOQ:

replace(val("hello world"), "llo", "y")

Translates to the following dialect specific expressions:

-- ACCESS, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO, VERTICA, YUGABYTEDB
replace('hello world', 'llo', 'y')

-- ASE
str_replace('hello world', 'llo', 'y')

-- SQLITE
"replace"('hello world', 'llo', 'y')

-- TERADATA
oreplace('hello world', 'llo', 'y')

-- DERBY, REDSHIFT
/* UNSUPPORTED */
 

4.7.11.13. REVERSE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The REVERSE() function reverses a string.

SELECT reverse('hello');
create.select(reverse("hello")).fetch();

The result being

+---------+
| reverse |
+---------+
| olleh   |
+---------+

Dialect support

This example using jOOQ:

reverse("hello")

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, HSQLDB, MARIADB, MYSQL, ORACLE, POSTGRES, 
-- SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, TERADATA, TRINO, YUGABYTEDB
reverse('hello')

-- ACCESS, DB2, DERBY, FIREBIRD, H2, HANA, INFORMIX, MEMSQL, REDSHIFT, SQLITE, SYBASE, VERTICA
/* UNSUPPORTED */
 

4.7.11.14. RIGHT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RIGHT() function calculates the substring of a given string starting from the right end. See also SUBSTRING, LEFT

SELECT right('hello world', 5);
create.select(right("hello world", 5)).fetch();

The result being

+-----------+
| right |
+-------+
| world |
+-------+

Dialect support

This example using jOOQ:

right("hello world", 5)

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, VERTICA, 
-- YUGABYTEDB
right('hello world', 5)

-- DERBY
substr(
  'hello world',
  (length('hello world') + (1 - 5))
)

-- ORACLE, SQLITE
substr(
  'hello world',
  -5
)

-- TRINO
substring(
  'hello world',
  -5
)
 

4.7.11.15. RPAD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RPAD() pads a string at the right end. See also LPAD.

SELECT rpad('hello', 10, '.');
create.select(rpad(val("hello"), 10, '.')).fetch();

The result being

+------------+
| rpad       |
+------------+
| hello..... |
+------------+

Dialect support

This example using jOOQ:

rpad(val("hello"), 10, '.')

Translates to the following dialect specific expressions:

-- ACCESS
('hello' & replace(space(10 - len('hello')), ' ', '.'))

-- ASE
('hello' || replicate(
  '.',
  (10 - char_length('hello'))
))

-- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- POSTGRES, TERADATA, VERTICA
rpad('hello', 10, '.')

-- SQLDATAWAREHOUSE, SQLSERVER
('hello' + replicate(
  '.',
  (10 - len('hello'))
))

-- SQLITE
'hello' || substr("replace"(hex(zeroblob(10)), '00', '.'), 1, 10 - length('hello'))

-- SYBASE
('hello' || repeat(
  '.',
  (10 - length('hello'))
))

-- BIGQUERY, DERBY, DUCKDB, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.11.16. RTRIM

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The RTRIM() function trims a string from the right end, stripping it of whitespace. See also LTRIM and TRIM.

SELECT rtrim('  hello  ');
create.select(rtrim("  hello  ")).fetch();

The result being

+---------+
| rtrim   |
+---------+
|   hello |
+---------+

Dialect support

This example using jOOQ:

rtrim("  hello  ")

Translates to the following dialect specific expressions:

-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
rtrim('  hello  ')

-- FIREBIRD
trim(TRAILING FROM '  hello  ')
 

4.7.11.17. SPACE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SPACE() function repeats a space character a number of times. This is convenience for REPEAT, as available natively in SQL Server, for example.

SELECT 'a' || space(3) || 'b';
create.select(val("a").concat(space(3)).concat(val("b")).fetch();

The result being

+-------+
| space |
+-------+
| a   b |
+-------+

Dialect support

This example using jOOQ:

space(3)

Translates to the following dialect specific expressions:

-- ASE, AURORA_MYSQL, DB2, EXASOL, H2, MARIADB, MYSQL, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, VERTICA
space(3)

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, HSQLDB, POSTGRES, YUGABYTEDB
repeat(' ', 3)

-- FIREBIRD, HANA, INFORMIX, MEMSQL, ORACLE, TERADATA, TRINO
rpad(' ', 3, ' ')

-- SQLITE
' ' || substr("replace"(hex(zeroblob(3)), '00', ' '), 1, 3 - length(' '))

-- ACCESS, DERBY, REDSHIFT
/* UNSUPPORTED */
 

4.7.11.18. SUBSTRING

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SUBSTRING() function calculates the substring of a string given a starting position and optionally, a length.. See also LEFT, RIGHT

SELECT
  substring('hello world', 7),
  substring('hello world', 7, 1);
create.select(
  substring("hello world", 7),
  substring("hello world", 7, 1)).fetch();

The result being

+-----------+-----------+
| substring | substring |
+-----------+-----------+
| world     | w         |
+-----------+-----------+

Dialect support

This example using jOOQ:

substring(val("hello world"), 7)

Translates to the following dialect specific expressions:

-- ACCESS
mid('hello world', 7)

-- ASE, SQLDATAWAREHOUSE, SQLSERVER
substring('hello world', 7, 2147483647)

-- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, 
-- POSTGRES, REDSHIFT, SNOWFLAKE, SYBASE, TRINO, VERTICA, YUGABYTEDB
substring('hello world', 7)

-- DB2, DERBY, INFORMIX, ORACLE, SQLITE
substr('hello world', 7)

-- FIREBIRD, TERADATA
substring('hello world' FROM 7)
 

4.7.11.19. TRANSLATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The TRANSLATE() function translates a set of characters to another set of characters within a string, based on matching positions within the search and replacement string.

SELECT translate('1 * [2 + 3]', '[]', '()');
create.select(translate(val("1 * [2 + 3]"), "[]", "()")).fetch();

The result being

+-------------+
| translate   |
+-------------+
| 1 * (2 + 3) |
+-------------+

Dialect support

This example using jOOQ:

translate(val("1 * [2 + 3]"), "[]", "()")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, EXASOL, H2, HSQLDB, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, TRINO, VERTICA, 
-- YUGABYTEDB
translate('1 * [2 + 3]', '[]', '()')

-- DB2
translate('1 * [2 + 3]', '()', '[]')

-- TERADATA
otranslate('1 * [2 + 3]', '[]', '()')

-- ACCESS, ASE, AURORA_MYSQL, DERBY, DUCKDB, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, 
-- SQLITE, SYBASE
/* UNSUPPORTED */
 

4.7.11.20. TRIM

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The TRIM() function trims a string from both ends, stripping it of whitespace. See also LTRIM and RTRIM.

SELECT trim('  hello  ');
create.select(trim("  hello  ")).fetch();

The result being

+-------+
| trim  |
+-------+
| hello |
+-------+

Dialect support

This example using jOOQ:

trim("  hello  ")

Translates to the following dialect specific expressions:

-- ACCESS, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, 
-- VERTICA, YUGABYTEDB
trim('  hello  ')

-- ASE, SQLDATAWAREHOUSE
ltrim(rtrim('  hello  '))
 

4.7.11.21. UPPER

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The UPPER() function transforms a string into upper case.

SELECT upper('hello');
create.select(upper("hello")).fetch();

The result being

+-------+
| upper |
+-------+
| HELLO |
+-------+

Dialect support

This example using jOOQ:

upper("hello")

Translates to the following dialect specific expressions:

-- ACCESS
ucase('hello')

-- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, 
-- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
upper('hello')
 

4.7.12. Datetime functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Datetime functions are useful to calculate date time arithmetic and formatting.

Many functions in this section come with two flavours supporting both the JDBC datetime data types, and the JSR 310 types. These include:

Some temporal SQL data types could not be represented canonically with historic JDBC types, but only with JSR 310 types. These include:

 

4.7.12.1. CURRENT_DATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL DATE type (represented by java.sql.Date).

SELECT current_date;
create.select(currentDate()).fetch();

The result being something like

+--------------+
| current_date |
+--------------+
| 2020-02-03   |
+--------------+

Dialect support

This example using jOOQ:

currentDate()

Translates to the following dialect specific expressions:

-- ACCESS
DATE()

-- ASE, AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_date()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, 
-- SQLITE, TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_DATE

-- INFORMIX
CURRENT YEAR TO DAY

-- ORACLE
trunc(current_date)

-- SQLDATAWAREHOUSE, SQLSERVER
convert(DATE, current_timestamp)

-- SYBASE
CURRENT DATE
 

4.7.12.2. CURRENT_LOCALDATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL DATE type (represented by java.time.LocalDate).

This does the same as CURRENT_DATE except that the client type representation uses JSR-310 types.

SELECT current_date;
create.select(currentLocalDate()).fetch();

The result being something like

+--------------+
| current_date |
+--------------+
| 2020-02-03   |
+--------------+

Dialect support

This example using jOOQ:

currentLocalDate()

Translates to the following dialect specific expressions:

-- ACCESS
DATE()

-- ASE, AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_date()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, 
-- SQLITE, TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_DATE

-- INFORMIX
CURRENT YEAR TO DAY

-- ORACLE
trunc(current_date)

-- SQLDATAWAREHOUSE, SQLSERVER
convert(DATE, current_timestamp)

-- SYBASE
CURRENT DATE
 

4.7.12.3. CURRENT_LOCALDATETIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIMESTAMP type (represented by java.time.LocalDateTime).

This does the same as CURRENT_TIMESTAMP except that the client type representation uses JSR-310 types.

SELECT current_timestamp;
create.select(currentLocalDateTime()).fetch();

The result being something like

+-----------------------+
| current_timestamp     |
+-----------------------+
|   2020-02-03 15:30:45 |
+-----------------------+

Dialect support

This example using jOOQ:

currentLocalDateTime()

Translates to the following dialect specific expressions:

-- ACCESS
now()

-- ASE
current_bigdatetime()

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_timestamp()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, ORACLE, POSTGRES, 
-- REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_TIMESTAMP

-- INFORMIX
CURRENT YEAR TO FRACTION (5)

-- SYBASE
CURRENT TIMESTAMP
 

4.7.12.4. CURRENT_LOCALTIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIME type (represented by java.time.LocalTime).

This does the same as CURRENT_TIME except that the client type representation uses JSR-310 types.

SELECT current_time;
create.select(currentLocalTime()).fetch();

The result being something like

+--------------+
| current_time |
+--------------+
|     15:30:45 |
+--------------+

Dialect support

This example using jOOQ:

currentLocalTime()

Translates to the following dialect specific expressions:

-- ACCESS
TIME()

-- ASE, AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_time()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, SQLITE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_TIME

-- EXASOL, ORACLE
current_timestamp

-- INFORMIX
CURRENT HOUR TO SECOND

-- SQLDATAWAREHOUSE, SQLSERVER
convert(TIME, current_timestamp)

-- SYBASE
CURRENT TIME
 

4.7.12.5. CURRENT_OFFSETDATETIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIMESTAMP WITH TIME ZONE type (represented by java.time.OffsetDateTime).

This does the same as CURRENT_TIMESTAMP except that a cast is added, and the client type representation uses JSR-310 types.

SELECT current_timestamp;
create.select(currentOffsetDateTime()).fetch();

The result being something like

+-----------------------+
| current_timestamp     |
+-----------------------+
|   2020-02-03 15:30:45 |
+-----------------------+

Dialect support

This example using jOOQ:

currentOffsetDateTime()

Translates to the following dialect specific expressions:

-- ACCESS
cstr(now())

-- ASE
CAST(current_bigdatetime() AS timestamp with time zone)

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
CAST(current_timestamp() AS timestamp with time zone)

-- AURORA_POSTGRES, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, ORACLE, POSTGRES, REDSHIFT, SQLITE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
CAST(CURRENT_TIMESTAMP AS timestamp with time zone)

-- COCKROACHDB
CAST(CURRENT_TIMESTAMP AS timestamptz)

-- INFORMIX
CAST(CURRENT YEAR TO FRACTION (5) AS timestamp with time zone)

-- SNOWFLAKE
CAST(current_timestamp() AS timestamp_tz)

-- SQLDATAWAREHOUSE, SQLSERVER
CAST(CURRENT_TIMESTAMP AS datetimeoffset)

-- SYBASE
CAST(CURRENT TIMESTAMP AS timestamp with time zone)
 

4.7.12.6. CURRENT_OFFSETTIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIME WITH TIME ZONE type (represented by java.time.OffsetTime).

This does the same as CURRENT_TIME except that a cast is added, and the client type representation uses JSR-310 types.

SELECT current_time;
create.select(currentOffsetTime()).fetch();

The result being something like

+--------------+
| current_time |
+--------------+
|     15:30:45 |
+--------------+

Dialect support

This example using jOOQ:

currentOffsetTime()

Translates to the following dialect specific expressions:

-- ACCESS
cstr(TIME())

-- ASE, AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
CAST(current_time() AS time with time zone)

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, SQLITE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
CAST(CURRENT_TIME AS time with time zone)

-- EXASOL
CAST(current_timestamp AS time with time zone)

-- INFORMIX
CAST(CURRENT HOUR TO SECOND AS time with time zone)

-- ORACLE
CAST(current_timestamp AS timestamp with time zone)

-- SQLDATAWAREHOUSE, SQLSERVER
CAST(convert(TIME, current_timestamp) AS time with time zone)

-- SYBASE
CAST(CURRENT TIME AS time with time zone)
 

4.7.12.7. CURRENT_TIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIME type (represented by java.sql.Time).

SELECT current_time;
create.select(currentTime()).fetch();

The result being something like

+--------------+
| current_time |
+--------------+
|     15:30:45 |
+--------------+

Dialect support

This example using jOOQ:

currentTime()

Translates to the following dialect specific expressions:

-- ACCESS
TIME()

-- ASE, AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_time()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, FIREBIRD, H2, HANA, HSQLDB, POSTGRES, REDSHIFT, SQLITE, 
-- TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_TIME

-- EXASOL, ORACLE
current_timestamp

-- INFORMIX
CURRENT HOUR TO SECOND

-- SQLDATAWAREHOUSE, SQLSERVER
convert(TIME, current_timestamp)

-- SYBASE
CURRENT TIME
 

4.7.12.8. CURRENT_TIMESTAMP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Get the current server time as a SQL TIMESTAMP type (represented by java.sql.Timestamp).

SELECT current_timestamp;
create.select(currentTimestamp()).fetch();

The result being something like

+-----------------------+
| current_timestamp     |
+-----------------------+
|   2020-02-03 15:30:45 |
+-----------------------+

Dialect support

This example using jOOQ:

currentTimestamp()

Translates to the following dialect specific expressions:

-- ACCESS
now()

-- ASE
current_bigdatetime()

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_timestamp()

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, ORACLE, POSTGRES, 
-- REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, TERADATA, TRINO, VERTICA, YUGABYTEDB
CURRENT_TIMESTAMP

-- INFORMIX
CURRENT YEAR TO FRACTION (5)

-- SYBASE
CURRENT TIMESTAMP
 

4.7.12.9. DATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 DATE string literal into a SQL DATE type (represented by java.sql.Date).

SELECT CAST('2020-02-03' AS DATE);
create.select(date("2020-02-03")).fetch();

The result being

+------------+
| date       |
+------------+
| 2020-02-03 |
+------------+

Dialect support

This example using jOOQ:

date("2020-02-03")

Translates to the following dialect specific expressions:

-- ACCESS
#2020/02/03#

-- ASE, SQLITE, SYBASE
'2020-02-03'

-- AURORA_MYSQL, MEMSQL, MYSQL
{d '2020-02-03'}

-- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, TERADATA, VERTICA
DATE '2020-02-03'

-- DERBY
DATE('2020-02-03')

-- INFORMIX
DATETIME(2020-02-03) YEAR TO DAY

-- SQLDATAWAREHOUSE, SQLSERVER
CAST('2020-02-03' AS date)

-- BIGQUERY, DUCKDB, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.10. DATEADD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Add an interval of type java.lang.Number (number of days) or org.jooq.types.Interval (SQL interval type) to a date (represented by java.sql.Date).

SELECT DATE '2020-02-03' + 3;
create.select(dateAdd(Date.valueOf("2020-02-03"), 3)).fetch();

The result being

+------------+
| date_add   |
+------------+
| 2020-02-06 |
+------------+

Dialect support

This example using jOOQ:

dateAdd(Date.valueOf("2020-02-03"), 3)

Translates to the following dialect specific expressions:

-- ACCESS
dateadd('d', 3, #2020/02/03#)

-- ASE, SYBASE
dateadd(DAY, 3, '2020-02-03')

-- AURORA_MYSQL, MEMSQL, MYSQL
date_add({d '2020-02-03'}, INTERVAL 3 DAY)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, ORACLE, POSTGRES, REDSHIFT, VERTICA, YUGABYTEDB
(DATE '2020-02-03' + 3)

-- BIGQUERY
timestamp_add(DATE '2020-02-03', INTERVAL 3 DAY)

-- DB2, HSQLDB
(DATE '2020-02-03' + (3) day)

-- DERBY
CAST({fn timestampadd(SQL_TSI_DAY, 3, DATE('2020-02-03')) } AS DATE)

-- FIREBIRD, SNOWFLAKE
dateadd(DAY, 3, DATE '2020-02-03')

-- HANA
add_days(DATE '2020-02-03', 3)

-- INFORMIX
(DATETIME(2020-02-03) YEAR TO DAY + 3 UNITS DAY)

-- MARIADB
date_add(DATE '2020-02-03', INTERVAL 3 DAY)

-- SQLDATAWAREHOUSE, SQLSERVER
dateadd(DAY, 3, CAST('2020-02-03' AS date))

-- SQLITE
strftime('%Y-%m-%d %H:%M:%f', '2020-02-03', (CAST(3 AS varchar) || ' day'))

-- TERADATA
DATE '2020-02-03' + CAST(3 || ' 00:00:00' AS INTERVAL DAY TO SECOND)

-- TRINO
date_add('day', 3, DATE '2020-02-03')
 

4.7.12.11. DATEDIFF

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Subtract two SQL DATE types (represented by java.sql.Date).

This function comes in two flavours:

MySQL 2 argument version

In MySQL, there is a 2 argument verison of the DATEDIFF() function, where the result produces the number of days between the two dates. The argument order is in the order of the difference notation: end_date - start_date

SELECT DATEDIFF(
  DATE '2020-02-03',
  DATE '2020-02-01');
create.select(dateDiff(
  Date.valueOf("2020-02-03"),
  Date.valueOf("2020-02-01"))).fetch();

The result being

+------------+
| datediff   |
+------------+
|          2 |
+------------+

Dialect support

This example using jOOQ:

dateDiff(Date.valueOf("2020-02-03"), Date.valueOf("2020-02-01"))

Translates to the following dialect specific expressions:

-- ACCESS
datediff('d', #2020/02/01#, #2020/02/03#)

-- ASE, SYBASE
datediff(DAY, '2020-02-01', '2020-02-03')

-- AURORA_MYSQL, MEMSQL, MYSQL
datediff({d '2020-02-03'}, {d '2020-02-01'})

-- AURORA_POSTGRES, COCKROACHDB, ORACLE, POSTGRES, YUGABYTEDB
(DATE '2020-02-03' - DATE '2020-02-01')

-- BIGQUERY
date_diff(DATE '2020-02-03', DATE '2020-02-01', DAY)

-- DB2
(days(DATE '2020-02-03') - days(DATE '2020-02-01'))

-- DERBY
{fn timestampdiff(sql_tsi_day, DATE('2020-02-01'), DATE('2020-02-03')) }

-- DUCKDB, EXASOL
CAST((DATE '2020-02-03' - DATE '2020-02-01') AS int)

-- FIREBIRD, H2, HSQLDB, SNOWFLAKE, VERTICA
datediff(DAY, DATE '2020-02-01', DATE '2020-02-03')

-- HANA
days_between(DATE '2020-02-01', DATE '2020-02-03')

-- INFORMIX
CAST((DATETIME(2020-02-03) YEAR TO DAY - DATETIME(2020-02-01) YEAR TO DAY) AS integer)

-- MARIADB
datediff(DATE '2020-02-03', DATE '2020-02-01')

-- REDSHIFT
datediff('day', DATE '2020-02-01', DATE '2020-02-03')

-- SQLDATAWAREHOUSE, SQLSERVER
datediff(DAY, CAST('2020-02-01' AS date), CAST('2020-02-03' AS date))

-- SQLITE
(strftime('%s', '2020-02-03') - strftime('%s', '2020-02-01')) / 86400

-- TERADATA
CAST((DATE '2020-02-03' - DATE '2020-02-01') AS integer)

-- TRINO
date_diff('day', DATE '2020-02-01', DATE '2020-02-03')

SQL Server 3 argument version

In SQL Server, there is a 3 argument verison of the DATEDIFF() function, where the result produces the number of date part periods between the two dates, with the dates being TRUNC-ed to the relevant date part. The argument order is in the order of the interval notation: [start_date, end_date]. This version is supported only in jOOQ 3.14+

 

4.7.12.12. DATESUB

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Subtract an interval of type java.lang.Number (number of days) or org.jooq.types.Interval (SQL interval type) from a date (represented by java.sql.Date).

SELECT DATE '2020-02-03' - 2;
create.select(dateSub(Date.valueOf("2020-02-03"), 2)).fetch();

The result being

+------------+
| date_sub   |
+------------+
| 2020-02-01 |
+------------+

Dialect support

This example using jOOQ:

dateSub(Date.valueOf("2020-02-03"), 2)

Translates to the following dialect specific expressions:

-- ACCESS
dateadd('d', -2, #2020/02/03#)

-- ASE, SYBASE
dateadd(DAY, -2, '2020-02-03')

-- AURORA_MYSQL, MEMSQL, MYSQL
date_add({d '2020-02-03'}, INTERVAL -2 DAY)

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, REDSHIFT, YUGABYTEDB
(DATE '2020-02-03' + -2)

-- BIGQUERY
timestamp_sub(DATE '2020-02-03', INTERVAL 2 DAY)

-- DB2, HSQLDB
(DATE '2020-02-03' - (2) day)

-- DERBY
CAST({fn timestampadd(SQL_TSI_DAY, -2, DATE('2020-02-03')) } AS DATE)

-- DUCKDB, EXASOL, H2, ORACLE, VERTICA
(DATE '2020-02-03' - 2)

-- FIREBIRD, SNOWFLAKE
dateadd(DAY, -2, DATE '2020-02-03')

-- HANA
add_days(DATE '2020-02-03', -2)

-- INFORMIX
(DATETIME(2020-02-03) YEAR TO DAY - 2 UNITS DAY)

-- MARIADB
date_add(DATE '2020-02-03', INTERVAL -2 DAY)

-- SQLDATAWAREHOUSE, SQLSERVER
dateadd(DAY, -2, CAST('2020-02-03' AS date))

-- SQLITE
strftime('%Y-%m-%d %H:%M:%f', '2020-02-03', (CAST(-2 AS varchar) || ' day'))

-- TERADATA
DATE '2020-02-03' - CAST(2 || ' 00:00:00' AS INTERVAL DAY TO SECOND)

-- TRINO
date_add('day', -2, DATE '2020-02-03')
 

4.7.12.13. DAY

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the DAY value from a datetime value.

The DAY function is a short version of the EXTRACT, passing a DatePart.DAY value as an argument.

SELECT day(DATE '2020-02-03');
create.select(day(Date.valueOf("2020-02-03"))).fetch();

The result being

+-----+
| day |
+-----+
|   3 |
+-----+

Dialect support

This example using jOOQ:

day(Date.valueOf("2020-02-03"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('d', #2020/02/03 00:00:00#)

-- ASE, SYBASE
datepart(dd, '2020-02-03 00:00:00.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(DAY FROM {ts '2020-02-03 00:00:00.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(DAY FROM TIMESTAMP '2020-02-03 00:00:00.0')

-- BIGQUERY
extract(DAY FROM DATETIME '2020-02-03 00:00:00.0')

-- DB2
DAY(TIMESTAMP '2020-02-03 00:00:00.0')

-- DERBY
DAY(TIMESTAMP('2020-02-03 00:00:00.0'))

-- INFORMIX
DAY(DATETIME(2020-02-03 00:00:00.0) YEAR TO FRACTION)

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(dd, CAST('2020-02-03 00:00:00.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%d', '2020-02-03 00:00:00.0') AS int)
 

4.7.12.14. EXTRACT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract a org.jooq.DatePart from a datetime value.

SELECT EXTRACT(MONTH FROM DATE '2020-02-03');
create.select(extract(Date.valueOf("2020-02-03"), DatePart.MONTH)).fetch();

The result being

+-------+
| month |
+-------+
|     2 |
+-------+

Dialect support

This example using jOOQ:

extract(Date.valueOf("2020-02-03"), DatePart.MONTH)

Translates to the following dialect specific expressions:

-- ACCESS
datepart('m', #2020/02/03 00:00:00#)

-- ASE, SYBASE
datepart(mm, '2020-02-03 00:00:00.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(MONTH FROM {ts '2020-02-03 00:00:00.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(MONTH FROM TIMESTAMP '2020-02-03 00:00:00.0')

-- BIGQUERY
extract(MONTH FROM DATETIME '2020-02-03 00:00:00.0')

-- DB2
MONTH(TIMESTAMP '2020-02-03 00:00:00.0')

-- DERBY
MONTH(TIMESTAMP('2020-02-03 00:00:00.0'))

-- INFORMIX
MONTH(DATETIME(2020-02-03 00:00:00.0) YEAR TO FRACTION)

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(mm, CAST('2020-02-03 00:00:00.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%m', '2020-02-03 00:00:00.0') AS int)
 

4.7.12.15. HOUR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the HOUR value from a datetime value.

The HOUR function is a short version of the EXTRACT, passing a DatePart.HOUR value as an argument.

SELECT hour(TIMESTAMP '2020-02-03 15:30:45');
create.select(hour(Timestamp.valueOf("2020-02-03 15:30:45"))).fetch();

The result being

+------+
| hour |
+------+
|   15 |
+------+

Dialect support

This example using jOOQ:

hour(Timestamp.valueOf("2020-02-03 15:30:45"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('h', #2020/02/03 15:30:45#)

-- ASE, SYBASE
datepart(hh, '2020-02-03 15:30:45.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(HOUR FROM {ts '2020-02-03 15:30:45.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(HOUR FROM TIMESTAMP '2020-02-03 15:30:45.0')

-- BIGQUERY
extract(HOUR FROM DATETIME '2020-02-03 15:30:45.0')

-- DB2
HOUR(TIMESTAMP '2020-02-03 15:30:45.0')

-- DERBY
HOUR(TIMESTAMP('2020-02-03 15:30:45.0'))

-- INFORMIX
CAST(DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION AS CAST(DATETIME HOUR TO HOUR AS CAST(CHAR(2) AS INT)))

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(hh, CAST('2020-02-03 15:30:45.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%H', '2020-02-03 15:30:45.0') AS int)
 

4.7.12.16. LOCALDATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 DATE string literal into a SQL DATE type (represented by java.time.LocalDate).

This does the same as DATE except that the client type representation uses JSR-310 types.

SELECT CAST('2020-02-03' AS DATE);
create.select(localDate("2020-02-03")).fetch();

The result being

+------------+
| date       |
+------------+
| 2020-02-03 |
+------------+

Dialect support

This example using jOOQ:

localDate("2020-02-03")

Translates to the following dialect specific expressions:

-- ACCESS
#2020/02/03#

-- ASE, SQLITE, SYBASE
'2020-02-03'

-- AURORA_MYSQL, MEMSQL, MYSQL
{d '2020-02-03'}

-- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, TERADATA, VERTICA
DATE '2020-02-03'

-- DERBY
DATE('2020-02-03')

-- INFORMIX
DATETIME(2020-02-03) YEAR TO DAY

-- SQLDATAWAREHOUSE, SQLSERVER
CAST('2020-02-03' AS date)

-- BIGQUERY, DUCKDB, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.17. LOCALDATETIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 TIMESTAMP string literal into a SQL TIMESTAMP type (represented by java.time.LocalDateTime).

This does the same as TIMESTAMP except that the client type representation uses JSR-310 types.

SELECT CAST('2020-02-03 15:30:45' AS TIMESTAMP);
create.select(localDateTime("2020-02-03 15:30:45")).fetch();

The result being

+---------------------+
| timestamp           |
+---------------------+
| 2020-02-03 15:30:45 |
+---------------------+

Dialect support

This example using jOOQ:

localDateTime("2020-02-03 15:30:45")

Translates to the following dialect specific expressions:

-- ACCESS
#2020/02/03 15:30:45#

-- ASE, SQLITE, SYBASE
'2020-02-03 15:30:45.0'

-- AURORA_MYSQL, MEMSQL, MYSQL
{ts '2020-02-03 15:30:45.0'}

-- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, TERADATA, VERTICA
TIMESTAMP '2020-02-03 15:30:45.0'

-- DERBY
TIMESTAMP('2020-02-03 15:30:45.0')

-- INFORMIX
DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION

-- SQLDATAWAREHOUSE, SQLSERVER
CAST('2020-02-03 15:30:45.0' AS DATETIME2)

-- BIGQUERY, DUCKDB, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.18. LOCALTIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 TIME string literal into a SQL TIME type (represented by java.time.LocalTime).

This does the same as TIME except that the client type representation uses JSR-310 types.

SELECT CAST('15:30:45' AS TIME);
create.select(localTime("15:30:45")).fetch();

The result being

+----------+
| time     |
+----------+
| 15:30:45 |
+----------+

Dialect support

This example using jOOQ:

localTime("15:30:45")

Translates to the following dialect specific expressions:

-- ACCESS, AURORA_MYSQL, MEMSQL, MYSQL
{t '15:30:45'}

-- ASE, SQLITE, SYBASE
'15:30:45'

-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, MARIADB, POSTGRES, TERADATA, VERTICA
TIME '15:30:45'

-- DERBY
TIME('15:30:45')

-- INFORMIX
DATETIME(15:30:45) HOUR TO SECOND

-- ORACLE
TIMESTAMP '1970-01-01 15:30:45'

-- SQLDATAWAREHOUSE, SQLSERVER
CAST(CAST('15:30:45' AS time) AS time)

-- BIGQUERY, DUCKDB, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.19. MINUTE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the MINUTE value from a datetime value.

The MINUTE function is a short version of the EXTRACT, passing a DatePart.MINUTE value as an argument.

SELECT minute(TIMESTAMP '2020-02-03 15:30:45');
create.select(minute(Timestamp.valueOf("2020-02-03 15:30:45"))).fetch();

The result being

+--------+
| minute |
+--------+
|     30 |
+--------+

Dialect support

This example using jOOQ:

minute(Timestamp.valueOf("2020-02-03 15:30:45"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('n', #2020/02/03 15:30:45#)

-- ASE, SYBASE
datepart(mi, '2020-02-03 15:30:45.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(MINUTE FROM {ts '2020-02-03 15:30:45.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(MINUTE FROM TIMESTAMP '2020-02-03 15:30:45.0')

-- BIGQUERY
extract(MINUTE FROM DATETIME '2020-02-03 15:30:45.0')

-- DB2
MINUTE(TIMESTAMP '2020-02-03 15:30:45.0')

-- DERBY
MINUTE(TIMESTAMP('2020-02-03 15:30:45.0'))

-- INFORMIX
CAST(DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION AS CAST(DATETIME MINUTE TO MINUTE AS CAST(CHAR(2) AS INT)))

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(mi, CAST('2020-02-03 15:30:45.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%M', '2020-02-03 15:30:45.0') AS int)
 

4.7.12.20. MONTH

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the MONTH value from a datetime value.

The MONTH function is a short version of the EXTRACT, passing a DatePart.MONTH value as an argument.

SELECT month(DATE '2020-02-03');
create.select(month(Date.valueOf("2020-02-03"))).fetch();

The result being

+-------+
| month |
+-------+
|     2 |
+-------+

Dialect support

This example using jOOQ:

month(Date.valueOf("2020-02-03"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('m', #2020/02/03 00:00:00#)

-- ASE, SYBASE
datepart(mm, '2020-02-03 00:00:00.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(MONTH FROM {ts '2020-02-03 00:00:00.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(MONTH FROM TIMESTAMP '2020-02-03 00:00:00.0')

-- BIGQUERY
extract(MONTH FROM DATETIME '2020-02-03 00:00:00.0')

-- DB2
MONTH(TIMESTAMP '2020-02-03 00:00:00.0')

-- DERBY
MONTH(TIMESTAMP('2020-02-03 00:00:00.0'))

-- INFORMIX
MONTH(DATETIME(2020-02-03 00:00:00.0) YEAR TO FRACTION)

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(mm, CAST('2020-02-03 00:00:00.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%m', '2020-02-03 00:00:00.0') AS int)
 

4.7.12.21. SECOND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the SECOND value from a datetime value.

The SECOND function is a short version of the EXTRACT, passing a DatePart.SECOND value as an argument.

SELECT second(TIMESTAMP '2020-02-03 15:30:45');
create.select(second(Timestamp.valueOf("2020-02-03 15:30:45"))).fetch();

The result being

+--------+
| second |
+--------+
|     45 |
+--------+

Dialect support

This example using jOOQ:

second(Timestamp.valueOf("2020-02-03 15:30:45"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('s', #2020/02/03 15:30:45#)

-- ASE, SYBASE
datepart(ss, '2020-02-03 15:30:45.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(SECOND FROM {ts '2020-02-03 15:30:45.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(SECOND FROM TIMESTAMP '2020-02-03 15:30:45.0')

-- BIGQUERY
extract(SECOND FROM DATETIME '2020-02-03 15:30:45.0')

-- DB2
SECOND(TIMESTAMP '2020-02-03 15:30:45.0')

-- DERBY
SECOND(TIMESTAMP('2020-02-03 15:30:45.0'))

-- INFORMIX
CAST(DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION AS CAST(DATETIME SECOND TO SECOND AS CAST(CHAR(2) AS INT)))

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(ss, CAST('2020-02-03 15:30:45.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%S', '2020-02-03 15:30:45.0') AS int)
 

4.7.12.22. TIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 TIME string literal into a SQL TIME type (represented by java.sql.Time).

SELECT CAST('15:30:45' AS TIME);
create.select(time("15:30:45")).fetch();

The result being

+----------+
| time     |
+----------+
| 15:30:45 |
+----------+

Dialect support

This example using jOOQ:

time("15:30:45")

Translates to the following dialect specific expressions:

-- ACCESS, AURORA_MYSQL, MEMSQL, MYSQL
{t '15:30:45'}

-- ASE, SQLITE, SYBASE
'15:30:45'

-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, MARIADB, POSTGRES, TERADATA, VERTICA
TIME '15:30:45'

-- DERBY
TIME('15:30:45')

-- INFORMIX
DATETIME(15:30:45) HOUR TO SECOND

-- ORACLE
TIMESTAMP '1970-01-01 15:30:45'

-- SQLDATAWAREHOUSE, SQLSERVER
CAST(CAST('15:30:45' AS time) AS time)

-- BIGQUERY, DUCKDB, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.23. TIMESTAMP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Convert an ISO 8601 TIMESTAMP string literal into a SQL TIMESTAMP type (represented by java.sql.Timestamp).

SELECT CAST('2020-02-03 15:30:45' AS TIMESTAMP);
create.select(timestamp("2020-02-03 15:30:45")).fetch();

The result being

+---------------------+
| timestamp           |
+---------------------+
| 2020-02-03 15:30:45 |
+---------------------+

Dialect support

This example using jOOQ:

timestamp("2020-02-03 15:30:45")

Translates to the following dialect specific expressions:

-- ACCESS
#2020/02/03 15:30:45#

-- ASE, SQLITE, SYBASE
'2020-02-03 15:30:45.0'

-- AURORA_MYSQL, MEMSQL, MYSQL
{ts '2020-02-03 15:30:45.0'}

-- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, TERADATA, VERTICA
TIMESTAMP '2020-02-03 15:30:45.0'

-- DERBY
TIMESTAMP('2020-02-03 15:30:45.0')

-- INFORMIX
DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION

-- SQLDATAWAREHOUSE, SQLSERVER
CAST('2020-02-03 15:30:45.0' AS DATETIME2)

-- BIGQUERY, DUCKDB, REDSHIFT, SNOWFLAKE, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.24. TIMESTAMPADD

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Add an interval of type java.lang.Number (number of days) or org.jooq.types.Interval (SQL interval type) to a timestamp (represented by java.sql.Timestamp).

SELECT DATE '2020-02-03 15:30:45' + INTERVAL 3 DAYS;
create.select(timestampAdd(Timestamp.valueOf("2020-02-03 15:30:45"), 3)).fetch();

The result being

+---------------------+
| timestamp_add       |
+---------------------+
| 2020-02-06 15:30:45 |
+---------------------+

Dialect support

This example using jOOQ:

timestampAdd(Timestamp.valueOf("2020-02-03 15:30:45"), 3)

Translates to the following dialect specific expressions:

-- ACCESS
dateadd('d', 3, #2020/02/03 15:30:45#)

-- ASE, SYBASE
dateadd(DAY, 3, '2020-02-03 15:30:45.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
date_add({ts '2020-02-03 15:30:45.0'}, INTERVAL 3 DAY)

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, REDSHIFT, YUGABYTEDB
(TIMESTAMP '2020-02-03 15:30:45.0' + 3 * INTERVAL '1 day')

-- BIGQUERY
timestamp_add(DATETIME '2020-02-03 15:30:45.0', INTERVAL 3 DAY)

-- DB2, HSQLDB
(TIMESTAMP '2020-02-03 15:30:45.0' + (3) day)

-- DERBY
{fn timestampadd(SQL_TSI_DAY, 3, TIMESTAMP('2020-02-03 15:30:45.0')) }

-- DUCKDB, EXASOL, H2, ORACLE, VERTICA
(TIMESTAMP '2020-02-03 15:30:45.0' + 3)

-- FIREBIRD, SNOWFLAKE
dateadd(DAY, 3, TIMESTAMP '2020-02-03 15:30:45.0')

-- HANA
add_days(TIMESTAMP '2020-02-03 15:30:45.0', 3)

-- INFORMIX
(DATETIME(2020-02-03 15:30:45.0) YEAR TO FRACTION + 3 UNITS DAY)

-- MARIADB
date_add(TIMESTAMP '2020-02-03 15:30:45.0', INTERVAL 3 DAY)

-- SQLDATAWAREHOUSE, SQLSERVER
dateadd(DAY, 3, CAST('2020-02-03 15:30:45.0' AS DATETIME2))

-- SQLITE
strftime('%Y-%m-%d %H:%M:%f', '2020-02-03 15:30:45.0', (CAST(3 AS varchar) || ' day'))

-- TERADATA
TIMESTAMP '2020-02-03 15:30:45.0' + CAST(3 || ' 00:00:00' AS INTERVAL DAY TO SECOND)

-- TRINO
date_add('day', 3, TIMESTAMP '2020-02-03 15:30:45.0')
 

4.7.12.25. TO_DATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Parse a string value to a SQL DATE type (represented by java.sql.Date) using a vendor specific formatting pattern.

The pattern is not translated by jOOQ for vendor agnosticity and may need to be adapted depending on the SQL dialect you're using.

SELECT TO_DATE('20200203', 'YYYYMMDD');
create.select(toDate("20200203", "YYYYMMDD")).fetch();

The result being

+------------+
| to_date    |
+------------+
| 2020-02-03 |
+------------+

Dialect support

This example using jOOQ:

toDate("20200203", "YYYYMMDD")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, BIGQUERY, DB2, EXASOL, HSQLDB, ORACLE, POSTGRES, VERTICA, YUGABYTEDB
to_date('20200203', 'YYYYMMDD')

-- SQLDATAWAREHOUSE, SQLSERVER
convert(
  date,
  '20200203',
  112
)

-- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, FIREBIRD, H2, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, 
-- SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.7.12.26. TO_LOCALDATE

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Parse a string value to a SQL DATE type (represented by java.time.LocalDate) using a vendor specific formatting pattern.

The pattern is not translated by jOOQ for vendor agnosticity and may need to be adapted depending on the SQL dialect you're using.

This does the same as TO_DATE except that the client type representation uses JSR-310 types.

SELECT TO_DATE('20200203', 'YYYYMMDD');
create.select(toLocalDate("20200203", "YYYYMMDD")).fetch();

The result being

+------------+
| to_date    |
+------------+
| 2020-02-03 |
+------------+

Dialect support

This example using jOOQ:

toLocalDate("20200203", "YYYYMMDD")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DB2, HSQLDB, ORACLE, POSTGRES, VERTICA
to_date('20200203', 'YYYYMMDD')

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.27. TO_LOCALDATETIME

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Parse a string value to a SQL TIMESTAMP type (represented by java.time.LocalDateTime) using a vendor specific formatting pattern.

The pattern is not translated by jOOQ for vendor agnosticity and may need to be adapted depending on the SQL dialect you're using.

This does the same as TO_TIMESTAMP except that the client type representation uses JSR-310 types.

SELECT TO_TIMESTAMP('20200203153045', 'YYYYMMDDHH24MISS');
create.select(toLocalDateTime("20200203153045", "YYYYMMDDHH24MISS")).fetch();

The result being

+---------------------+
| to_timestamp        |
+---------------------+
| 2020-02-03 15:30:45 |
+---------------------+

Dialect support

This example using jOOQ:

toLocalDateTime("20200203153045", "YYYYMMDDHH24MISS")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DB2, HSQLDB, ORACLE, POSTGRES, VERTICA
to_timestamp('20200203153045', 'YYYYMMDDHH24MISS')

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, INFORMIX, MARIADB, MEMSQL, 
-- MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.28. TO_TIMESTAMP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Parse a string value to a SQL TIMESTAMP type (represented by java.sql.Timestamp) using a vendor specific formatting pattern.

The pattern is not translated by jOOQ for vendor agnosticity and may need to be adapted depending on the SQL dialect you're using.

SELECT TO_TIMESTAMP('20200203153045', 'YYYYMMDDHH24MISS');
create.select(toTimestamp("20200203153045", "YYYYMMDDHH24MISS")).fetch();

The result being

+---------------------+
| to_timestamp        |
+---------------------+
| 2020-02-03 15:30:45 |
+---------------------+

Dialect support

This example using jOOQ:

toTimestamp("20200203153045", "YYYYMMDDHH24MISS")

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, DB2, EXASOL, HSQLDB, ORACLE, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB
to_timestamp('20200203153045', 'YYYYMMDDHH24MISS')

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, FIREBIRD, H2, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, 
-- REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO
/* UNSUPPORTED */
 

4.7.12.29. TRUNC

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Truncate a datetime value to the precision of a certain org.jooq.DatePart, or DatePart.DAY by default.

SELECT TRUNC(DATE '2020-02-03', 'YYYY');
create.select(trunc(Date.valueOf("2020-02-03", DatePart.YEAR))).fetch();

The result being

+------------+
| trunc      |
+------------+
| 2020-01-01 |
+------------+

Dialect support

This example using jOOQ:

trunc(Date.valueOf("2020-02-03"), DatePart.YEAR)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, VERTICA
date_trunc('year', DATE '2020-02-03')

-- BIGQUERY
date_trunc(
  DATE '2020-02-03',
  YEAR
)

-- DB2, ORACLE
trunc(DATE '2020-02-03', 'YYYY')

-- H2
PARSEDATETIME(FORMATDATETIME(DATE '2020-02-03', 'yyyy'), 'yyyy')

-- HSQLDB
trunc(DATE '2020-02-03', 'YY')

-- INFORMIX
trunc(DATETIME(2020-02-03) YEAR TO DAY, 'YEAR')

-- ACCESS, ASE, AURORA_MYSQL, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, 
-- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.12.30. YEAR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Extract the YEAR value from a datetime value.

The YEAR function is a short version of the EXTRACT, passing a DatePart.YEAR value as an argument.

SELECT year(DATE '2020-02-03');
create.select(year(Date.valueOf("2020-02-03"))).fetch();

The result being

+------+
| year |
+------+
| 2020 |
+------+

Dialect support

This example using jOOQ:

year(Date.valueOf("2020-02-03"))

Translates to the following dialect specific expressions:

-- ACCESS
datepart('yyyy', #2020/02/03 00:00:00#)

-- ASE, SYBASE
datepart(yy, '2020-02-03 00:00:00.0')

-- AURORA_MYSQL, MEMSQL, MYSQL
extract(YEAR FROM {ts '2020-02-03 00:00:00.0'})

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, MARIADB, ORACLE, POSTGRES, REDSHIFT, 
-- SNOWFLAKE, TERADATA, TRINO, VERTICA, YUGABYTEDB
extract(YEAR FROM TIMESTAMP '2020-02-03 00:00:00.0')

-- BIGQUERY
extract(YEAR FROM DATETIME '2020-02-03 00:00:00.0')

-- DB2
YEAR(TIMESTAMP '2020-02-03 00:00:00.0')

-- DERBY
YEAR(TIMESTAMP('2020-02-03 00:00:00.0'))

-- INFORMIX
YEAR(DATETIME(2020-02-03 00:00:00.0) YEAR TO FRACTION)

-- SQLDATAWAREHOUSE, SQLSERVER
datepart(yy, CAST('2020-02-03 00:00:00.0' AS DATETIME2))

-- SQLITE
CAST(strftime('%Y', '2020-02-03 00:00:00.0') AS int)
 

4.7.13. ARRAY functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard specifies an ARRAY data type, which allows for nesting collections of scalar values and even ROW expressions.

In order to operate on ARRAY data types, a few functions are made available by jOOQ.

 

4.7.13.1. ARRAY constructor

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In order to construct an ad-hoc ARRAY type from within a SQL query, the ARRAY constructor can be used.

SELECT ARRAY[1, 2]
create.select(array(1, 2)).fetch();

The result would look like this:

+----------+
| array    |
+----------+
| [ 1, 2 ] |
+----------+

Dialect support

This example using jOOQ:

array(1, 2)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, POSTGRES, TRINO, YUGABYTEDB
ARRAY[1, 2]

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, 
-- ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, VERTICA
/* UNSUPPORTED */
 

4.7.14. System functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some system functions are supported by jOOQ.

 

4.7.14.1. CURRENT_SCHEMA

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CURRENT_SCHEMA() function produces the dialect dependent expression to produce the current default schema for the JDBC connection.

SELECT current_schema;
create.select(currentSchema()).fetch();

The result being, for example

+----------------+
| current_schema |
+----------------+
| public         |
+----------------+

Dialect support

This example using jOOQ:

currentSchema()

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL
DATABASE()

-- AURORA_POSTGRES, COCKROACHDB, DB2, HSQLDB, POSTGRES, YUGABYTEDB
CURRENT_SCHEMA

-- DERBY
CURRENT SCHEMA

-- FIREBIRD, SQLITE
''

-- H2
SCHEMA()

-- ORACLE
user

-- SNOWFLAKE, VERTICA
CURRENT_SCHEMA()

-- SQLDATAWAREHOUSE, SQLSERVER
schema_name()

-- TERADATA
DATABASE

-- ACCESS, ASE, BIGQUERY, DUCKDB, EXASOL, HANA, INFORMIX, REDSHIFT, SYBASE, TRINO
/* UNSUPPORTED */
 

4.7.14.2. CURRENT_USER

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CURRENT_USER() function produces the dialect dependent expression to produce the currently connected user for the JDBC connection.

SELECT current_user;
create.select(currentUser()).fetch();

The result being, for example

+--------------+
| current_user |
+--------------+
| sa           |
+--------------+

Dialect support

This example using jOOQ:

currentUser()

Translates to the following dialect specific expressions:

-- ASE, INFORMIX, ORACLE
user

-- AURORA_MYSQL, H2, MARIADB, MEMSQL, MYSQL, SNOWFLAKE
current_user()

-- AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, FIREBIRD, HANA, HSQLDB, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, 
-- TERADATA, YUGABYTEDB
current_user

-- SQLITE
''

-- ACCESS, BIGQUERY, DUCKDB, EXASOL, REDSHIFT, TRINO, VERTICA
/* UNSUPPORTED */
 

4.7.15. Aggregate functions

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Aggregate functions work like Java java.util.stream.Collector, as they aggregate data from a group of data into a new data structure.

This section will first explain concepts common to many aggregate functions, and then proceed to explaining individual aggregate functions supported by jOOQ.

 

4.7.15.1. Grouping

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Aggregate functions aggregate data from groups of data into individual values. There are three main ways of forming such groups:

  • A GROUP BY clause is used to define the groups for which data is aggregated
  • No GROUP BY clause is defined, which means that all data from a SELECT statement (or subquery) is aggregated into a single row
  • All aggregate functions can be used as window functions, in case of which they will aggregate the data of the specified window

Aggregation with GROUP BY

In the presence of GROUP BY, a SELECT statement transforms the output of its FROM clause into a new "virtual" set of tuples containing:

  • The column expressions of the GROUP BY clause. In the overall data set, the values of these column expressions is unique.
  • A set of data corresponding to each row produced by the GROUP BY clause. This data set can be aggregated per group using aggregate functions.

Using GROUP BY means that a new set of rules need to be observed in the rest of the query:

An example:

SELECT AUTHOR_ID, count(*)
FROM BOOK
GROUP BY AUTHOR_ID;
create.select(BOOK.AUTHOR_ID, count())
      .from(BOOK)
      .groupBy(BOOK.AUTHOR_ID).fetch();

Producing:

+-----------+-------+
| AUTHOR_ID | count |
+-----------+-------+
|         1 |     2 |
|         2 |     2 |
+-----------+-------+

Per the rules imposed by GROUP BY, it would not be possible, for example, to project the BOOK.TITLE column, because it is not defined per author. An author has written many books, so we don't know what a BOOK.TITLE is supposed to mean. Only an aggregation, such as LISTAGG or ARRAY_AGG can reference BOOK.TITLE as an argument.

Aggregation without GROUP BY

In the absence of GROUP BY, a SELECT statement that contains at least one aggregate function in any of its clauses (e.g. HAVING, WINDOW, SELECT, or ORDER BY) will proceed to aggregating the entire data into a single row. There is an implied "empty grouping", i.e. a grouping that has no GROUP BY columns. These two are the same things:

SELECT count(*) FROM BOOK;
SELECT count(*) FROM BOOK GROUP BY ();

See also GROUPING SETS for more details about this empty GROUP BY syntax.

For example, using our sample database, which has 4 books with IDs 1-4, we can write:

SELECT count(*), sum(ID)
FROM BOOK
create.select(count(), sum(BOOK.ID))
      .from(BOOK).fetch();

Producing:

+----------+---------+
| count(*) | sum(ID) |
+----------+---------+
|        4 |      10 |
+----------+---------+

No other columns from the tables in the FROM clause may be projected by the SELECT clause, because they would not be defined for this single group. For example, no specific BOOK.TITLE is defined for the aggregated value of all books. Only an aggregation, such as LISTAGG or ARRAY_AGG can reference BOOK.TITLE as an argument.

However, any expression whose components do not depend on content of the group is allowed. For example, it is possible to combine aggregate functions and constant expressions like this:

SELECT count(*) + sum(ID) + 1
FROM BOOK
create.select(count().plus(sum(BOOK.ID)).plus(1))
      .from(BOOK).fetch();

Producing:

+------+
| plus |
+------+
|   15 |
+------+
 

4.7.15.2. Distinctness

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

A useful thing to do when aggregating data is to remove duplicate input first, prior to aggregation. A few aggregate functions support a DISTINCT keyword for that purpose. For example, we can query

SELECT
  count(AUTHOR_ID),
  count(DISTINCT AUTHOR_ID),
  group_concat(AUTHOR_ID),
  group_concat(DISTINCT AUTHOR_ID)
FROM BOOK
create.select(
         count(BOOK.AUTHOR_ID),
         countDistinct(BOOK.AUTHOR_ID),
         groupConcat(BOOK.AUTHOR_ID),
         groupConcatDistinct(BOOK.AUTHOR_ID))
      .from(BOOK).fetch();

Producing:

+-------+----------------+--------------+-----------------------+
| count | count_distinct | group_concat | group_concat_distinct |
+-------+----------------+--------------+-----------------------+
|     4 |              2 | 1, 1, 2, 2   | 1, 2                  |
+-------+----------------+--------------+-----------------------+

If DISTINCT is available through the jOOQ API, it is always appended to the aggregate function name, such as count() and countDistinct(). sum() and sumDistinct(), etc.

 

4.7.15.3. Filtering

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The SQL standard specifies an optional FILTER clause, that can be appended to all aggregate functions including aggregated window functions. This is very useful, for example, to implement "pivot" tables, such as the following:

SELECT
  count(*),
  count(*) FILTER (WHERE TITLE LIKE 'A%'),
  count(*) FILTER (WHERE TITLE LIKE '%A%')
FROM BOOK
create.select(
         count(),
         count().filterWhere(BOOK.TITLE.like("A%")),
         count().filterWhere(BOOK.TITLE.like("%A%")))
      .from(BOOK)

Producing:

+-------+-------+-------+
| count | count | count |
+-------+-------+-------+
|     4 |     1 |     2 |
+-------+-------+-------+

Or, with GROUP BY:

SELECT
  AUTHOR_ID,
  count(*),
  count(*) FILTER (WHERE TITLE LIKE 'A%'),
  count(*) FILTER (WHERE TITLE LIKE '%A%')
FROM BOOK
GROUP BY AUTHOR_ID
create.select(
         BOOK.AUTHOR_ID,
         count(),
         count().filterWhere(BOOK.TITLE.like("A%")),
         count().filterWhere(BOOK.TITLE.like("%A%")))
      .from(BOOK)
      .groupBy(BOOK.AUTHOR_ID)

Producing:

+-----------+-------+-------+-------+
| AUTHOR_ID | count | count | count |
+-----------+-------+-------+-------+
|         1 |     2 |     1 |     1 |
|         2 |     2 |     0 |     1 |
+-----------+-------+-------+-------+

It is usually a good idea to calculate multiple aggregate functions in a single query, if this is possible, and FILTER helps here.

Only a few dialects implement native support for the FILTER clause. In all other databases, jOOQ emulates the clause using a CASE expression. Aggregate functions exclude NULL values from aggregation.

Dialect support

This example using jOOQ:

count().filterWhere(BOOK.TITLE.like("A%"))

Translates to the following dialect specific expressions:

-- ACCESS
count(SWITCH(BOOK.TITLE LIKE 'A%', 1))

-- ASE, AURORA_MYSQL, DB2, DERBY, EXASOL, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, REDSHIFT, SQLDATAWAREHOUSE, 
-- SQLSERVER, SYBASE, TERADATA, VERTICA
count(CASE
  WHEN BOOK.TITLE LIKE 'A%' THEN 1
END)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, FIREBIRD, H2, HSQLDB, POSTGRES, SQLITE, TRINO, YUGABYTEDB
count(*) FILTER (WHERE BOOK.TITLE LIKE 'A%')

-- BIGQUERY
countif((BOOK.TITLE LIKE 'A%'))

-- SNOWFLAKE
count_if((BOOK.TITLE LIKE 'A%'))
 

4.7.15.4. Ordering

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some aggregate functions allow for ordering their inputs to produce an ordered output. These aggregate functions allow for specifying an optional ORDER BY clause in their argument list. This is not to be confused with the WITHIN GROUP (ORDER BY ..) clause, which is required for ordering inputs to produce a single, unordered output.

This makes a lot of sense with aggregations that produce the aggregated values in a nested or formatted data structure, such as, for example:

  • ARRAY_AGG, which aggregates data into an array.
  • COLLECT, which aggregates data into a nested table (Oracle).
  • LISTAGG, which aggregates data into a string. The standard LISTAGG function, unfortunately, inconsistently uses the WITHIN GROUP syntax. MySQL's GROUP_CONCAT is more consistent with the rest.

An example using ARRAY_AGG could look like this:

SELECT
  array_agg(ID),
  array_agg(ID ORDER BY ID DESC)
FROM BOOK
create.select(
         arrayAgg(BOOK.ID),
         arrayAgg(BOOK.ID).orderBy(BOOK.ID.desc()))
      .from(BOOK)

Producing:

+--------------+--------------+
| array_agg    | array_agg    |
+--------------+--------------+
| [1, 3, 4, 2] | [4, 3, 2, 1] |
+--------------+--------------+

Notice that in the absence of an explicit ORDER BY clause, as always, the ordering is non deterministic.

 

4.7.15.5. Ordering WITHIN GROUP

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Some aggregate functions allow for ordering their inputs to produce an ordered output. These aggregate functions allow for specifying a mandatory WITHIN GROUP (ORDER BY ..) clause after the function. This is not to be confused with the aggregate ORDER BY clause, which allows for optionally ordering inputs to produce ordered output

Standard SQL talks about "ordered set aggregate functions" which come in three flavours

  • Hypothetical set functions: Functions that check for the position of a hypothetical value inside of an ordered set. These include RANK, DENSE_RANK, PERCENT_RANK, CUME_DIST.
  • Inverse distribution functions: Functions calculating a percentile over an ordered set, including PERCENTILE_CONT, PERCENTILE_DISC, or MODE.
  • LISTAGG, which is inconsistently using the WITHIN GROUP syntax, as it is used to order the output of the function, and isn't mandatory in all dialects.

An example for the PERCENTILE_CONT inverse distribution function is this:

SELECT
  percentile_cont(0.5) WITHIN GROUP (ORDER BY ID)
FROM BOOK
create.select(
         percentileCont(0.5).withinGroupOrderBy(BOOK.ID))
      .from(BOOK)

Producing the median BOOK.ID value:

+-----------------+
| percentile_cont |
+-----------------+
|             2.5 |
+-----------------+
 

4.7.15.6. Keeping

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

Oracle allows for restricting other aggregate functions using the KEEP() clause, which is supported by jOOQ. In Oracle, some aggregate functions (e.g. MIN, MAX, SUM, AVG, COUNT, VARIANCE, or STDDEV) can be restricted by this clause, hence org.jooq.AggregateFunction also allows for specifying it. Here is an example using this clause:

SUM(BOOK.AMOUNT_SOLD)
  KEEP(DENSE_RANK FIRST ORDER BY BOOK.AUTHOR_ID)
sum(BOOK.AMOUNT_SOLD)
  .keepDenseRankFirstOrderBy(BOOK.AUTHOR_ID)
 

4.7.15.7. ARRAY_AGG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The ARRAY_AGG aggregate function aggregates grouped values into an array. It supports being used with an ORDER BY clause.

SELECT
  array_agg(ID)
  array_agg(ID ORDER BY ID DESC)
FROM BOOK
create.select(
         arrayAgg(BOOK.ID),
         arrayAgg(BOOK.ID).orderBy(BOOK.ID.desc()))
      .from(BOOK)

Producing:

+--------------+--------------+
| array_agg    | array_agg    |
+--------------+--------------+
| [1, 3, 4, 2] | [4, 3, 2, 1] |
+--------------+--------------+

Dialect support

This example using jOOQ:

arrayAgg(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, BIGQUERY, COCKROACHDB, H2, HSQLDB, POSTGRES, TRINO, YUGABYTEDB
array_agg(BOOK.ID)

-- ACCESS, ASE, AURORA_MYSQL, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, 
-- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, VERTICA
/* UNSUPPORTED */
 

4.7.15.8. AVG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The AVG() aggregate function calculates the average value of all input values

SELECT avg(ID)
FROM BOOK
create.select(avg(BOOK.ID))
      .from(BOOK)

Producing:

+-----+
| avg |
+-----+
| 2.5 |
+-----+

Dialect support

This example using jOOQ:

avg(BOOK.ID)

Translates to the following dialect specific expressions:

-- All dialects
avg(BOOK.ID)
 

4.7.15.9. BOOL_AND

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BOOL_AND() aggregate function calculates the boolean conjunction of all the boolean values in the aggregated group. In other words, this is:

  • TRUE if the argument is TRUE for every row in the group.
  • FALSE if at the argument is FALSE for at least one row in the group.

As with most aggregate functions, NULL values are not aggregated, so three valued logic does not apply here.

SELECT
  bool_and(ID < 4),
  bool_and(ID < 5)
FROM BOOK
create.select(
         boolAnd(BOOK.ID.lt(4)),
         boolAnd(BOOK.ID.lt(5)))
      .from(BOOK)

Producing:

+----------+----------+
| bool_and | bool_and |
+----------+----------+
| false    | true     |
+----------+----------+

Dialect support

This example using jOOQ:

boolAnd(BOOK.ID.lt(4))

Translates to the following dialect specific expressions:

-- ACCESS
(min(SWITCH(BOOK.ID < 4, 1, TRUE, 0)) = 1)

-- ASE, DB2, FIREBIRD, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN 1
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN 0
END

-- AURORA_MYSQL, DERBY, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLITE
(min(CASE
  WHEN BOOK.ID < 4 THEN 1
  ELSE 0
END) = 1)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, TRINO, VERTICA, YUGABYTEDB
bool_and((BOOK.ID < 4))

-- BIGQUERY
logical_and((BOOK.ID < 4))

-- EXASOL
every((BOOK.ID < 4))

-- HANA, ORACLE
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN TRUE
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN FALSE
END

-- INFORMIX
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN CAST('t' AS boolean)
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN CAST('f' AS boolean)
END

-- SNOWFLAKE
booland_agg((BOOK.ID < 4))
 

4.7.15.10. BOOL_OR

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The BOOL_OR() aggregate function calculates the boolean disjunction of all the boolean values in the aggregated group. In other words, this is:

  • FALSE if the argument is FALSE for every row in the group.
  • TRUE if at the argument is TRUE for at least one row in the group.

As with most aggregate functions, NULL values are not aggregated, so three valued logic does not apply here.

SELECT
  bool_or(ID >= 4),
  bool_or(ID >= 5)
FROM BOOK
create.select(
         boolOr(BOOK.ID.ge(4)),
         boolOr(BOOK.ID.ge(5)))
      .from(BOOK)

Producing:

+---------+---------+
| bool_or | bool_or |
+---------+---------+
| true    | false   |
+---------+---------+

Dialect support

This example using jOOQ:

boolOr(BOOK.ID.ge(4))

Translates to the following dialect specific expressions:

-- ACCESS
(max(SWITCH(BOOK.ID >= 4, 1, TRUE, 0)) = 1)

-- ASE, DB2, FIREBIRD, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA
CASE
  WHEN max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1 THEN 1
  WHEN NOT (max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1) THEN 0
END

-- AURORA_MYSQL, DERBY, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLITE
(max(CASE
  WHEN BOOK.ID >= 4 THEN 1
  ELSE 0
END) = 1)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, TRINO, VERTICA, YUGABYTEDB
bool_or((BOOK.ID >= 4))

-- BIGQUERY
logical_or((BOOK.ID >= 4))

-- EXASOL
any((BOOK.ID >= 4))

-- HANA, ORACLE
CASE
  WHEN max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1 THEN TRUE
  WHEN NOT (max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1) THEN FALSE
END

-- INFORMIX
CASE
  WHEN max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1 THEN CAST('t' AS boolean)
  WHEN NOT (max(CASE
    WHEN BOOK.ID >= 4 THEN 1
    ELSE 0
  END) = 1) THEN CAST('f' AS boolean)
END

-- SNOWFLAKE
boolor_agg((BOOK.ID >= 4))
 

4.7.15.11. COLLECT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COLLECT() aggregate function is Oracle's vendor specific version of the standard SQL ARRAY_AGG function. It produces a structurally typed array, which is implemented behind the scenes as a nominally typed, system-generated array. It supports being used with an ORDER BY clause.

The following example is using an auxiliary data type and casting the COLLECT() result to that type.

CREATE TYPE NUMBERS AS TABLE OF NUMBER(10);
SELECT CAST(collect(ID ORDER BY ID) AS NUMBERS);
FROM BOOK;
create.select(
         collect(BOOK.ID, NumbersRecord.class).orderBy(BOOK.ID))
      .from(BOOK)

Producing:

+--------------+
| collect      |
+--------------+
| [1, 2, 3, 4] |
+--------------+
 

4.7.15.12. COUNT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The COUNT() aggregate function comes in two flavours:

  • COUNT(*): This version counts the number of tuples in a group, regardless of any contents, including NULL values.
  • COUNT(expression): This version counts the number of non-NULL expression evaluations per group.

The second version can be used to emulate the FILTER clause as the argument expression effectively filters out NULL values. Alternatively, in the case of a LEFT JOIN, the outer joined rows can be counted using an expression on the primary key, because COUNT(*) always produces at least one row.

SELECT
  AUTHOR.ID,
  count(*),
  count(BOOK.ID)
FROM AUTHOR
LEFT JOIN BOOK
ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select(
         AUTHOR.ID,
         count(),
         count(BOOK.ID))
      .from(AUTHOR)
      .leftJoin(BOOK)
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))

Producing (assuming the presence of an author with ID = 3, but without books):

+----+----------+----------------+
| ID | count(*) | count(BOOK.ID) |
+----+----------+----------------+
|  1 |        2 |              2 |
|  2 |        2 |              2 |
|  3 |        1 |              0 |
+----+----------+----------------+

Dialect support

This example using jOOQ:

count(BOOK.ID)

Translates to the following dialect specific expressions:

-- All dialects
count(BOOK.ID)
 

4.7.15.13. CUME_DIST

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The CUME_DIST() hypothetical set function calculates the cumulative distribution of the hypothetical value, i.e. the relative rank from 1/N to 1 (PERCENT_RANK produces values from 0 to 1)

SELECT
  cume_dist(0) WITHIN GROUP (ORDER BY ID),
  cume_dist(2) WITHIN GROUP (ORDER BY ID),
  cume_dist(4) WITHIN GROUP (ORDER BY ID)
FROM BOOK
create.select(
         cumeDist(val(0)).withinGroupOrderBy(BOOK.ID),
         cumeDist(val(2)).withinGroupOrderBy(BOOK.ID),
         cumeDist(val(4)).withinGroupOrderBy(BOOK.ID))
      .from(BOOK)

Producing:

+--------------+--------------+--------------+
| cume_dist(0) | cume_dist(2) | cume_dist(4) |
+--------------+--------------+--------------+
|          0.2 |          0.6 |          1.0 |
+--------------+--------------+--------------+

Dialect support

This example using jOOQ:

cumeDist(val(0)).withinGroupOrderBy(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, H2, ORACLE, POSTGRES, YUGABYTEDB
cume_dist(0) WITHIN GROUP (ORDER BY BOOK.ID)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.7.15.14. DENSE_RANK

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The DENSE_RANK() hypothetical set function calculates the rank without gaps of the hypothetical value, i.e. dense ranks will be 1, 1, 1, 2, 3, 3, 4 (RANK produces values with gaps, e.g. 1, 1, 1, 4, 5, 5, 7)

SELECT
  dense_rank(0) WITHIN GROUP (ORDER BY AUTHOR_ID),
  dense_rank(1) WITHIN GROUP (ORDER BY AUTHOR_ID),
  dense_rank(2) WITHIN GROUP (ORDER BY AUTHOR_ID)
FROM BOOK
create.select(
         denseRank(val(0)).withinGroupOrderBy(BOOK.AUTHOR_ID),
         denseRank(val(2)).withinGroupOrderBy(BOOK.AUTHOR_ID),
         denseRank(val(4)).withinGroupOrderBy(BOOK.AUTHOR_ID))
      .from(BOOK)

Producing:

+---------------+---------------+---------------+
| dense_rank(0) | dense_rank(1) | dense_rank(2) |
+---------------+---------------+---------------+
|             1 |             1 |             2 |
+---------------+---------------+---------------+

Dialect support

This example using jOOQ:

denseRank(val(0)).withinGroupOrderBy(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_POSTGRES, H2, ORACLE, POSTGRES, YUGABYTEDB
dense_rank(0) WITHIN GROUP (ORDER BY BOOK.ID)

-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, 
-- MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA
/* UNSUPPORTED */
 

4.7.15.15. EVERY

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The EVERY() aggregate function is the standard SQL version of the BOOL_AND function.

SELECT
  every(ID < 4),
  every(ID < 5)
FROM BOOK
create.select(
         every(BOOK.ID.lt(4)),
         every(BOOK.ID.lt(5)))
      .from(BOOK)

Producing:

+---------------+---------------+
| every(ID < 4) | every(ID < 5) |
+---------------+---------------+
| false         | true          |
+---------------+---------------+

Dialect support

This example using jOOQ:

every(BOOK.ID.lt(4))

Translates to the following dialect specific expressions:

-- ACCESS
(min(SWITCH(BOOK.ID < 4, 1, TRUE, 0)) = 1)

-- ASE, DB2, FIREBIRD, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN 1
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN 0
END

-- AURORA_MYSQL, DERBY, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLITE
(min(CASE
  WHEN BOOK.ID < 4 THEN 1
  ELSE 0
END) = 1)

-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, TRINO, VERTICA, YUGABYTEDB
bool_and((BOOK.ID < 4))

-- BIGQUERY
logical_and((BOOK.ID < 4))

-- EXASOL
every((BOOK.ID < 4))

-- HANA, ORACLE
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN TRUE
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN FALSE
END

-- INFORMIX
CASE
  WHEN min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1 THEN CAST('t' AS boolean)
  WHEN NOT (min(CASE
    WHEN BOOK.ID < 4 THEN 1
    ELSE 0
  END) = 1) THEN CAST('f' AS boolean)
END

-- SNOWFLAKE
booland_agg((BOOK.ID < 4))
 

4.7.15.16. GROUP_CONCAT

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The GROUP_CONCAT() aggregate function is the MySQL version of the standard SQL LISTAGG function, to concatenate aggregate data into a string. It supports being used with an ORDER BY clause, which uses the expected syntax, unlike LISTAGG(), which uses the WITHIN GROUP syntax.

SELECT
  group_concat(ID),
  group_concat(ID ORDER BY ID),
  group_concat(ID SEPARATOR '; '),
  group_concat(ID ORDER BY ID SEPARATOR '; '),
FROM BOOK
create.select(
         groupConcat(BOOK.ID),
         groupConcat(BOOK.ID).orderBy(BOOK.ID),
         groupConcat(BOOK.ID).separator("; "),
         groupConcat(BOOK.ID).orderBy(BOOK.ID).separator("; "))
      .from(BOOK).fetch();

Producing:

+--------------+--------------+--------------+--------------+
| group_concat | group_concat | group_concat | group_concat |
+--------------+--------------+--------------+--------------+
| 1, 3, 4, 2   | 1, 2, 3, 4   | 1; 3; 4; 2   | 1; 2; 3; 4   |
+--------------+--------------+--------------+--------------+

Dialect support

This example using jOOQ:

groupConcat(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL
group_concat(BOOK.ID SEPARATOR ',')

-- AURORA_POSTGRES, HANA, POSTGRES
string_agg(CAST(BOOK.ID AS varchar), ',')

-- BIGQUERY, COCKROACHDB
string_agg(CAST(BOOK.ID AS string), ',')

-- DB2, EXASOL, REDSHIFT
listagg(BOOK.ID, ',')

-- ORACLE
listagg(BOOK.ID, ',') WITHIN GROUP (ORDER BY NULL)

-- SQLITE
group_concat(BOOK.ID, ',')

-- SQLSERVER
string_agg(CAST(BOOK.ID AS varchar(max)), ',')

-- SYBASE
list(CAST(BOOK.ID AS varchar), ',')

-- TERADATA
substring(xmlserialize(CONTENT xmlagg((',' || CAST(BOOK.ID AS varchar(32000)))) AS varchar(32000)) FROM 2)

-- TRINO
listagg(CAST(BOOK.ID AS varchar), ',') WITHIN GROUP (ORDER BY NULL)

-- ACCESS, ASE, DERBY, DUCKDB, FIREBIRD, INFORMIX, SNOWFLAKE, SQLDATAWAREHOUSE, VERTICA, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.15.17. LISTAGG

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The LISTAGG() aggregate function aggregates data into a string. It uses the WITHIN GROUP syntax.

SELECT
  listagg(ID) WITHIN GROUP (ORDER BY ID),
  listagg(ID, '; ') WITHIN GROUP (ORDER BY ID),
FROM BOOK
create.select(
         listagg(BOOK.ID).withinGroupOrderBy(BOOK.ID),
         listagg(BOOK.ID, "; ").withinGroupOrderBy(BOOK.ID))
      .from(BOOK).fetch();

Producing:

+------------+--------------+
| listagg    | listagg      |
+------------+--------------+
| 1, 2, 3, 4 | 1; 2; 3; 4   |
+------------+--------------+

Dialect support

This example using jOOQ:

listAgg(BOOK.AUTHOR_ID, ",").withinGroupOrderBy(BOOK.ID)

Translates to the following dialect specific expressions:

-- AURORA_MYSQL, H2, HSQLDB, MARIADB, MYSQL
group_concat(BOOK.AUTHOR_ID ORDER BY BOOK.ID SEPARATOR ',')

-- AURORA_POSTGRES, HANA, POSTGRES
string_agg(CAST(BOOK.AUTHOR_ID AS varchar), ',' ORDER BY BOOK.ID)

-- BIGQUERY, COCKROACHDB
string_agg(CAST(BOOK.AUTHOR_ID AS string), ',' ORDER BY BOOK.ID)

-- DB2, EXASOL, ORACLE, REDSHIFT
listagg(BOOK.AUTHOR_ID, ',') WITHIN GROUP (ORDER BY BOOK.ID)

-- SQLSERVER
string_agg(CAST(BOOK.AUTHOR_ID AS varchar(max)), ',') WITHIN GROUP (ORDER BY BOOK.ID)

-- SYBASE
list(CAST(BOOK.AUTHOR_ID AS varchar), ',' ORDER BY BOOK.ID)

-- TERADATA
substring(xmlserialize(CONTENT xmlagg((',' || CAST(BOOK.AUTHOR_ID AS varchar(32000))) ORDER BY BOOK.ID) AS varchar(32000)) FROM 2)

-- TRINO
listagg(CAST(BOOK.AUTHOR_ID AS varchar), ',') WITHIN GROUP (ORDER BY BOOK.ID)

-- ACCESS, ASE, DERBY, DUCKDB, FIREBIRD, INFORMIX, MEMSQL, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, VERTICA, YUGABYTEDB
/* UNSUPPORTED */
 

4.7.15.18. MAX

Applies to ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

The MAX() aggregate function calculates the maximum value of all input values

SELECT max(ID)
FROM BOOK
create.select(max(BOOK.ID))
      .from(BOOK)

Producing:

+-----+
| max |
+-----+
|   4 |
+-----+

Dialect support

This example using jOOQ:

max(BOOK.ID)

Translates to the following dialect specific expressions:

-- All dialects
max(BOOK.ID)
<