All versions: 3.11 | 3.10 | 3.9 | 3.8 | 3.7 | Development versions: 3.12 | Unsupported versions: 3.6 | 3.5 | 3.4 | 3.3 | 3.2 | 2.6

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.

  • 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
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.
Tutorials
3.4.1.
jOOQ in 7 easy steps
3.4.1.1.
Step 1: Preparation
3.4.1.2.
Step 2: Your database
3.4.1.3.
Step 3: Code generation
3.4.1.4.
Step 4: Connect to your database
3.4.1.5.
Step 5: Querying
3.4.1.6.
Step 6: Iterating
3.4.1.7.
Step 7: Explore!
3.4.2.
Using jOOQ in modern IDEs
3.4.3.
Using jOOQ with Spring and Apache DBCP
3.4.4.
Using jOOQ with Flyway
3.4.5.
Using jOOQ with JAX-RS
3.4.6.
A simple web application with jOOQ
3.5.
jOOQ and Java 8
3.6.
jOOQ and JavaFX
3.7.
jOOQ and Nashorn
3.8.
jOOQ and Scala
3.9.
jOOQ and Groovy
3.10.
jOOQ and Kotlin
3.11.
jOOQ and NoSQL
3.12.
jOOQ and JPA
3.13.
Dependencies
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 class
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.
Object qualification
4.2.6.2.
Runtime schema and table mapping
4.2.6.3.
Identifier style
4.2.6.4.
Keyword style
4.2.6.5.
Parameter types
4.2.6.6.
Statement Type
4.2.6.7.
Execute Logging
4.2.6.8.
Optimistic Locking
4.2.6.9.
Auto-attach Records
4.2.6.10.
Updatable Primary Keys
4.2.6.11.
Reflection caching
4.2.6.12.
Fetch Warnings
4.2.6.13.
Return All Columns On Store
4.2.6.14.
Map JPA Annotations
4.2.6.15.
JDBC Flags
4.2.6.16.
IN-list Padding
4.2.6.17.
Backslash Escaping
4.2.6.18.
Scalar subqueries for stored functions
4.3.
SQL Statements (DML)
4.3.1.
jOOQ's DSL and model API
4.3.2.
The WITH clause
4.3.3.
The SELECT statement
4.3.3.1.
The SELECT clause
4.3.3.2.
The FROM clause
4.3.3.3.
The JOIN clause
4.3.3.4.
Implicit JOIN
4.3.3.5.
The WHERE clause
4.3.3.6.
The CONNECT BY clause
4.3.3.7.
The GROUP BY clause
4.3.3.8.
The HAVING clause
4.3.3.9.
The WINDOW clause
4.3.3.10.
The ORDER BY clause
4.3.3.11.
The LIMIT .. OFFSET clause
4.3.3.12.
The WITH TIES clause
4.3.3.13.
The SEEK clause
4.3.3.14.
The FOR UPDATE clause
4.3.3.15.
UNION, INTERSECTION and EXCEPT
4.3.3.16.
Oracle-style hints
4.3.3.17.
Lexical and logical SELECT clause order
4.3.4.
The INSERT statement
4.3.4.1.
INSERT .. VALUES
4.3.4.2.
INSERT .. DEFAULT VALUES
4.3.4.3.
INSERT .. SET
4.3.4.4.
INSERT .. SELECT
4.3.4.5.
INSERT .. ON DUPLICATE KEY
4.3.4.6.
INSERT .. RETURNING
4.3.5.
The UPDATE statement
4.3.6.
The DELETE statement
4.3.7.
The MERGE statement
4.4.
SQL Statements (DDL)
4.4.1.
The SET statement
4.4.2.
The ALTER statement
4.4.3.
The CREATE statement
4.4.4.
The DROP statement
4.4.5.
The TRUNCATE statement
4.4.6.
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.3.
Joined tables
4.6.4.
The VALUES() table constructor
4.6.5.
Nested SELECTs
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.
The DUAL table
4.7.
Column expressions
4.7.1.
Table columns
4.7.2.
Aliased columns
4.7.3.
Cast expressions
4.7.4.
Datatype coercions
4.7.5.
Collations
4.7.6.
Arithmetic expressions
4.7.7.
String concatenation
4.7.8.
General functions
4.7.9.
Numeric functions
4.7.10.
Bitwise functions
4.7.11.
String functions
4.7.12.
Case sensitivity with strings
4.7.13.
Date and time functions
4.7.14.
System functions
4.7.15.
Aggregate functions
4.7.16.
Window functions
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.
Tuples or row value expressions
4.8.
Conditional expressions
4.8.1.
Condition building
4.8.2.
AND, OR, NOT boolean operators
4.8.3.
Comparison predicate
4.8.4.
Boolean operator precedence
4.8.5.
Comparison predicate (degree > 1)
4.8.6.
Quantified comparison predicate
4.8.7.
NULL predicate
4.8.8.
NULL predicate (degree > 1)
4.8.9.
DISTINCT predicate
4.8.10.
BETWEEN predicate
4.8.11.
BETWEEN predicate (degree > 1)
4.8.12.
LIKE predicate
4.8.13.
IN predicate
4.8.14.
IN predicate (degree > 1)
4.8.15.
EXISTS predicate
4.8.16.
OVERLAPS predicate
4.8.17.
Query By Example (QBE)
4.9.
Dynamic SQL
4.10.
Plain SQL
4.11.
Plain SQL Templating Language
4.12.
SQL Parser
4.12.1.
SQL Parser API
4.12.2.
SQL Parser CLI
4.12.3.
SQL Parser Grammar
4.13.
Names and identifiers
4.14.
Bind values and parameters
4.14.1.
Indexed parameters
4.14.2.
Named parameters
4.14.3.
Inlined parameters
4.14.4.
SQL injection
4.15.
QueryParts
4.15.1.
SQL rendering
4.15.2.
Pretty printing SQL
4.15.3.
Variable binding
4.15.4.
Custom data type bindings
4.15.5.
Custom syntax elements
4.15.6.
Plain SQL QueryParts
4.15.7.
Serializability
4.15.8.
Custom SQL transformation
4.15.8.1.
Logging abbreviated bind values
4.16.
Zero-based vs one-based APIs
4.17.
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.
Data type conversion
5.3.14.
Interning data
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.
Importing CSV
5.11.2.
Importing JSON
5.11.3.
Importing Records
5.11.4.
Importing Arrays
5.11.5.
Importing XML
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.18.
Mocking Connection
5.19.
Mock File Database
5.20.
Parsing Connection
5.21.
Diagnostics
5.21.1.
Too Many Rows
5.21.2.
Too Many Columns
5.21.3.
Duplicate Statements
5.21.4.
Repeated statements
5.21.5.
WasNull calls
5.22.
Logging
5.23.
Performance considerations
5.24.
Alternative execution models
5.24.1.
Using jOOQ with Spring's JdbcTemplate
5.24.2.
Using jOOQ with JPA
5.24.2.1.
Using jOOQ with JPA Native Query
5.24.2.2.
Using jOOQ with JPA entities
5.24.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.
Custom ordering of generated code
6.2.4.15.
Forced types
6.2.4.16.
Table valued functions
6.2.5.
Generate
6.2.5.1.
Global Artefacts
6.2.5.2.
Annotations
6.2.5.3.
Java Time Types
6.2.5.4.
Zero Scale Decimal Types
6.2.5.5.
Fully Qualified Types
6.2.6.
Output target configuration
6.3.
Programmatic generator configuration
6.4.
Custom generator strategies
6.5.
Matcher strategies
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.
Data type rewrites
6.17.
Custom data types and type conversion
6.18.
Custom data type binding
6.19.
Mapping generated catalogs and schemas
6.20.
Code generation for large schemas
6.21.
Code generation and version control
6.22.
JPADatabase: Code generation from entities
6.23.
XMLDatabase: Code generation from XML files
6.24.
DDLDatabase: Code generation from SQL files
6.25.
XMLGenerator: Generating XML
6.26.
Running the code generator with Maven
6.27.
Running the code generator with Ant
6.28.
Running the code generator with Gradle
6.29.
System properties governing code generation
7.
Tools
7.1.
API validation using the Checker Framework
7.2.
SQL 2 jOOQ Parser
7.3.
jOOQ Console
8.
Reference
8.1.
Supported RDBMS
8.2.
Data types
8.2.1.
BLOBs and CLOBs
8.2.2.
Unsigned integer types
8.2.3.
INTERVAL data types
8.2.4.
XML data types
8.2.5.
Geospacial data types
8.2.6.
CURSOR data types
8.2.7.
ARRAY and TABLE data types
8.2.8.
Oracle DATE data type
8.3.
SQL to DSL mapping rules
8.4.
Quality Assurance
8.5.
Migrating to jOOQ 3.0
8.6.
Credits

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!

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 http://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

 http://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: http://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

    http://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 Data Geekery™ GmbH partners

  • GSP and General SQL Parser are trademarks by Gudu Software Limited
  • SQL 2 jOOQ is a trademark by Data Geekery™ GmbH and Gudu Software Limited
  • Flyway is a trademark by Snow Mountain Labs UG (haftungsbeschränkt)

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
  • 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
  • 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
  • Laurent Pireyn
  • Luc Marchaud
  • Lukas Eder
  • Matti Tahvonen
  • Michael Doberenz
  • Michael Simons
  • Michał Kołodziejski
  • Miguel Gonzalez Sanchez
  • Nathaniel Fischer
  • Oliver Flege
  • Peter Ertl
  • Richard Bradley
  • Robin Stocker
  • Samy Deghou
  • Sander Plas
  • Sean Wellington
  • Sergey Epik
  • Sergey Zhuravlev
  • Stanislas Nanchen
  • Stephan Schroevers
  • Sugiharto Lim
  • Sven Jacobs
  • Szymon Jachim
  • Terence Zhang
  • Timothy Wilson
  • Timur Shaidullin
  • Thomas Darimont
  • Tsukasa Kitachi
  • Victor Bronstein
  • Victor Z. Peng
  • Vladimir Kulev
  • Vladimir Vinogradov
  • Vojtech Polivka
  • Wang Gaoyuan
  • Zoltan Tamasi

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

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.

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 // correspond to com.example.generated.Tables.BOOK.TITLE, com.example.generated.Tables.BOOK.TITLE
FK_BOOK_AUTHOR               // corresponds to 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.

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 );

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.

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 probably 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.
String sql = 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))
                   .getSQL();

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 PreparedStatement by default, this will generate a bind variable for "1948". Read more about bind variables here).

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

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. An example is given here:

// Fetch a SQL string from a jOOQ Query in order to manually execute it with another tool.
String sql = 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))
                   .getSQL();

The SQL string that you can generate as such can then be executed using JDBC directly, using Spring's JdbcTemplate, using Apache DbUtils and many other tools.

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

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

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

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.

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.

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

If you haven't already downloaded it, download jOOQ:
http://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.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.11.7</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.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.11.7</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.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro-java-6</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.pro-java-6</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.11.7</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.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq-meta</artifactId>
  <version>3.11.7</version>
</dependency>
<dependency>
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq-codegen</artifactId>
  <version>3.11.7</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:
http://dev.mysql.com/downloads/connector/j/

If you don't have a MySQL instance up and running yet, get XAMPP now! XAMPP is a simple installation bundle for Apache, MySQL, PHP and Perl

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`)
);

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 xmlns="http://www.jooq.org/xsd/jooq-codegen-3.11.0.xsd">
  <!-- Configure the database connection here -->
  <jdbc>
    <driver>com.mysql.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.codegen.JavaGenerator
         - org.jooq.codegen.ScalaGenerator
         Defaults to org.jooq.codegen.JavaGenerator -->
    <name>org.jooq.codegen.JavaGenerator</name>

    <database>
      <!-- The database type. The format here is:
           org.util.[database].[database]Database -->
      <name>org.jooq.meta.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 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:

generator.target.package - set this to the parent package you want to create for the generated classes. The setting of test.generated will cause the test.generated.Author and test.generated.AuthorRecord to be created

generator.target.directory - the directory to output to.

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

java -classpath jooq-3.11.7.jar;jooq-meta-3.11.7.jar;jooq-codegen-3.11.7.jar;mysql-connector-java-5.1.18-bin.jar;.
  org.jooq.codegen.GenerationTool library.xml

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

java -classpath jooq-3.11.7.jar:jooq-meta-3.11.7.jar:jooq-codegen-3.11.7.jar:mysql-connector-java-5.1.18-bin.jar:.
  org.jooq.codegen.GenerationTool library.xml

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.11.7 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

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.

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.

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();
        }
    }
}

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

... explore the Javadoc:
http://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:
http://ikaisays.com/2011/11/01/getting-started-with-jooq-a-tutorial/

Feel free to contribute a tutorial!

jOOQ and Spring are easy to integrate. In this example, we shall integrate:

Before you copy the manual examples, consider also these further resources:

Add the required Maven dependencies

For this example, we'll create the following Maven dependencies

<!-- Use this or the latest Spring RELEASE version -->
<properties>
    <org.springframework.version>3.2.3.RELEASE</org.springframework.version>
</properties>

<dependencies>

    <!-- Database access -->
    <dependency>
        <!-- Use org.jooq            for the Open Source Edition
                 org.jooq.pro        for commercial editions, 
                 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. 
                   Import the others manually from your distribution -->
        <groupId>org.jooq</groupId>
        <artifactId>jooq</artifactId>
        <version>3.11.7</version>
    </dependency>
    <dependency>
        <groupId>org.apache.commons</groupId>
        <artifactId>commons-dbcp2</artifactId>
        <version>2.0</version>
    </dependency>
    <dependency>
        <groupId>com.h2database</groupId>
        <artifactId>h2</artifactId>
        <version>1.3.168</version>
    </dependency>

    <!-- Logging -->
    <dependency>
        <groupId>log4j</groupId>
        <artifactId>log4j</artifactId>
        <version>1.2.16</version>
    </dependency>
    <dependency>
        <groupId>org.slf4j</groupId>
        <artifactId>slf4j-log4j12</artifactId>
        <version>1.7.5</version>
    </dependency>

    <!-- Spring (transitive dependencies are not listed explicitly) -->
    <dependency>
        <groupId>org.springframework</groupId>
        <artifactId>spring-context</artifactId>
        <version>${org.springframework.version}</version>
    </dependency>
    <dependency>
        <groupId>org.springframework</groupId>
        <artifactId>spring-jdbc</artifactId>
        <version>${org.springframework.version}</version>
    </dependency>

    <!-- Testing -->
    <dependency>
        <groupId>junit</groupId>
        <artifactId>junit</artifactId>
        <version>4.11</version>
        <type>jar</type>
        <scope>test</scope>
    </dependency>
    <dependency>
        <groupId>org.springframework</groupId>
        <artifactId>spring-test</artifactId>
        <version>${org.springframework.version}</version>
        <scope>test</scope>
    </dependency>
</dependencies>

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.

Create a minimal Spring configuration file

The above dependencies are configured together using a Spring Beans configuration:

<?xml version="1.0" encoding="UTF-8"?>

<beans xmlns="http://www.springframework.org/schema/beans"
       xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
       xmlns:tx="http://www.springframework.org/schema/tx"
       xsi:schemaLocation="
            http://www.springframework.org/schema/beans http://www.springframework.org/schema/beans/spring-beans.xsd
            http://www.springframework.org/schema/tx http://www.springframework.org/schema/tx/spring-tx-3.2.xsd">

    <!-- This is needed if you want to use the @Transactional annotation -->
    <tx:annotation-driven transaction-manager="transactionManager"/>

    <bean id="dataSource" class="org.apache.commons.dbcp2.BasicDataSource" destroy-method="close" >
        <!-- These properties are replaced by Maven "resources" -->
       <property name="url" value="${db.url}" />
       <property name="driverClassName" value="${db.driver}" />
       <property name="username" value="${db.username}" />
       <property name="password" value="${db.password}" />
    </bean>

    <!-- Configure Spring's transaction manager to use a DataSource -->
    <bean id="transactionManager"
        class="org.springframework.jdbc.datasource.DataSourceTransactionManager">
        <property name="dataSource" ref="dataSource" />
    </bean>

    <!-- Configure jOOQ's ConnectionProvider to use Spring's TransactionAwareDataSourceProxy,
         which can dynamically discover the transaction context -->
    <bean id="transactionAwareDataSource"
        class="org.springframework.jdbc.datasource.TransactionAwareDataSourceProxy">
        <constructor-arg ref="dataSource" />
    </bean>

    <bean class="org.jooq.impl.DataSourceConnectionProvider" name="connectionProvider">
        <constructor-arg ref="transactionAwareDataSource" />
    </bean>

    <!-- Configure the DSL object, optionally overriding jOOQ Exceptions with Spring Exceptions -->
    <bean id="dsl" class="org.jooq.impl.DefaultDSLContext">
        <constructor-arg ref="config" />
    </bean>
    
    <bean id="exceptionTranslator" class="org.jooq.example.spring.exception.ExceptionTranslator" />
    
    <!-- Invoking an internal, package-private constructor for the example
         Implement your own Configuration for more reliable behaviour -->
    <bean class="org.jooq.impl.DefaultConfiguration" name="config">
        <property name="SQLDialect"><value type="org.jooq.SQLDialect">H2</value></property>
        <property name="connectionProvider" ref="connectionProvider" />
        <property name="executeListenerProvider">
            <array>
                <bean class="org.jooq.impl.DefaultExecuteListenerProvider">
                    <constructor-arg index="0" ref="exceptionTranslator"/>
                </bean>
            </array>
        </property>
    </bean>
    
    <!-- This is the "business-logic" -->
    <bean id="books" class="org.jooq.example.spring.impl.DefaultBookService"/>
</beans>

Run a query using the above configuration:

With the above configuration, you should be ready to run queries pretty quickly. For instance, in an integration-test, you could use Spring to run JUnit:

@RunWith(SpringJUnit4ClassRunner.class)
@ContextConfiguration(locations = {"/jooq-spring.xml"})
public class QueryTest {

    @Autowired
    DSLContext create;

    @Test
    public void testJoin() throws Exception {
        // All of these tables were generated by jOOQ's Maven plugin
        Book b = BOOK.as("b");
        Author a = AUTHOR.as("a");
        BookStore s = BOOK_STORE.as("s");
        BookToBookStore t = BOOK_TO_BOOK_STORE.as("t");

        Result<Record3<String, String, Integer>> result =
        create.select(a.FIRST_NAME, a.LAST_NAME, countDistinct(s.NAME))
              .from(a)
              .join(b).on(b.AUTHOR_ID.eq(a.ID))
              .join(t).on(t.BOOK_ID.eq(b.ID))
              .join(s).on(t.BOOK_STORE_NAME.eq(s.NAME))
              .groupBy(a.FIRST_NAME, a.LAST_NAME)
              .orderBy(countDistinct(s.NAME).desc())
              .fetch();

        assertEquals(2, result.size());
        assertEquals("Paulo", result.getValue(0, a.FIRST_NAME));
        assertEquals("George", result.getValue(1, a.FIRST_NAME));

        assertEquals("Coelho", result.getValue(0, a.LAST_NAME));
        assertEquals("Orwell", result.getValue(1, a.LAST_NAME));

        assertEquals(Integer.valueOf(3), result.getValue(0, countDistinct(s.NAME)));
        assertEquals(Integer.valueOf(2), result.getValue(1, countDistinct(s.NAME)));
    }
}

Run a queries in an explicit transaction:

The following example shows how you can use Spring's TransactionManager to explicitly handle transactions:

@RunWith(SpringJUnit4ClassRunner.class)
@ContextConfiguration(locations = {"/jooq-spring.xml"})
@TransactionConfiguration(transactionManager="transactionManager")
public class TransactionTest {

    @Autowired DSLContext                   dsl;
    @Autowired DataSourceTransactionManager txMgr;
    @Autowired BookService                  books;

    @After
    public void teardown() {

        // Delete all books that were created in any test
        dsl.delete(BOOK).where(BOOK.ID.gt(4)).execute();
    }

    @Test
    public void testExplicitTransactions() {
        boolean rollback = false;

        TransactionStatus tx = txMgr.getTransaction(new DefaultTransactionDefinition());
        try {

            // This is a "bug". The same book is created twice, resulting in a
            // constraint violation exception
            for (int i = 0; i < 2; i++)
                dsl.insertInto(BOOK)
                   .set(BOOK.ID, 5)
                   .set(BOOK.AUTHOR_ID, 1)
                   .set(BOOK.TITLE, "Book 5")
                   .execute();

            Assert.fail();
        }
        
        // Upon the constraint violation, we explicitly roll back the transaction.
        catch (DataAccessException e) {
            txMgr.rollback(tx);
            rollback = true;
        }

        assertEquals(4, dsl.fetchCount(BOOK));
        assertTrue(rollback);
    }
}

Run queries using declarative transactions

Spring-TX has very powerful means to handle transactions declaratively, using the @Transactional annotation. The BookService that we had defined in the previous Spring configuration can be seen here:

public interface BookService {

    /**
     * Create a new book.
     * <p>
     * The implementation of this method has a bug, which causes this method to
     * fail and roll back the transaction.
     */
    @Transactional
    void create(int id, int authorId, String title);

}

And here is how we interact with it:

    @Test
    public void testDeclarativeTransactions() {
        boolean rollback = false;

        try {
        
            // The service has a "bug", resulting in a constraint violation exception
            books.create(5, 1, "Book 5");
            Assert.fail();
        }
        catch (DataAccessException ignore) {
            rollback = true;
        }

        assertEquals(4, dsl.fetchCount(BOOK));
        assertTrue(rollback);
    }

Run queries using jOOQ's transaction API

jOOQ has its own programmatic transaction API that can be used with Spring transactions by implementing the jOOQ org.jooq.TransactionProvider SPI and passing that to your jOOQ Configuration. More details about this transaction API can be found in the manual's section about transaction management.

You can try the above example yourself by downloading it from GitHub.

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 udpated, 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/master/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-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. 
               Import the others manually from your distribution -->
    <groupId>org.jooq</groupId>
    <artifactId>jooq</artifactId>
    <version>3.11.7</version>
</dependency>
<dependency>
    <groupId>com.h2database</groupId>
    <artifactId>h2</artifactId>
    <version>1.4.177</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>log4j</groupId>
    <artifactId>log4j</artifactId>
    <version>1.2.16</version>
</dependency>
<dependency>
    <groupId>org.slf4j</groupId>
    <artifactId>slf4j-log4j12</artifactId>
    <version>1.7.5</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 suggests 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-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. 
               Import the others manually from your distribution -->
    <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.11.7:generate (default) @ jooq-flyway-example ---
[INFO] --- jooq-codegen-maven:3.11.7: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));
        }
    }
}

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.

In some use-cases, having a lean, single-tier server-side architecture is desirable. Typically, such architectures expose a RESTful API implementing client code and the UI using something like AngularJS.

In Java, the standard API for RESTful applications is JAX-RS, which is part of JEE 7, along with a standard JSON implementation. But you can use JAX-RS also outside of a JEE container. The following example shows how to set up a simple license server using these technologies:

  • Maven for building and running
  • Jetty as a lightweight Servlet implementation
  • Jersey, the JAX-RS (JSR 311 & JSR 339) reference implementation
  • jOOQ as a data access layer

For the example, we'll use a PostgreSQL database.

Creating the license server database

We'll keep the example simple and use a LICENSE table to store all license keys and associated information, whereas a LOG_VERIFY table is used to log access to the license server. Here's the DDL:

CREATE TABLE LICENSE_SERVER.LICENSE (
  ID           SERIAL8      NOT NULL,

  LICENSE_DATE TIMESTAMP    NOT NULL,              -- The date when the license was issued
  LICENSEE     TEXT         NOT NULL,              -- The e-mail address of the licensee
  LICENSE      TEXT         NOT NULL,              -- The license key
  VERSION      VARCHAR(50)  NOT NULL DEFAULT '.*', -- The licensed version(s), a regular expression
  
  CONSTRAINT PK_LICENSE PRIMARY KEY (ID),
  CONSTRAINT UK_LICENSE UNIQUE (LICENSE)
);

CREATE TABLE LICENSE_SERVER.LOG_VERIFY (
  ID           SERIAL8      NOT NULL,

  LICENSEE     TEXT         NOT NULL,              -- The licensee whose license is being verified
  LICENSE      TEXT         NOT NULL,              -- The license key that is being verified
  REQUEST_IP   VARCHAR(50)  NOT NULL,              -- The request IP verifying the license
  VERSION      VARCHAR(50)  NOT NULL,              -- The version that is being verified
  MATCH        BOOLEAN      NOT NULL,              -- Whether the verification was successful
  
  CONSTRAINT PK_LOG_VERIFY PRIMARY KEY (ID)
);

To make things a bit more interesting (and secure), we'll also push license key generation into the database, by generating it from a stored function as such:

CREATE OR REPLACE FUNCTION LICENSE_SERVER.GENERATE_KEY(
    IN license_date TIMESTAMP WITH TIME ZONE,
    IN email TEXT
) RETURNS VARCHAR
AS $$
BEGIN
    RETURN 'license-key';
END;
$$ LANGUAGE PLPGSQL;

The actual algorithm might be using a secret salt to hash the function arguments. For the sake of a tutorial, a constant string will suffice.

Setting up the project

We're going to be setting up the jOOQ code generator using Maven

<?xml version="1.0" encoding="UTF-8"?>
<project xmlns="http://maven.apache.org/POM/4.0.0"
    xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
    xsi:schemaLocation="http://maven.apache.org/POM/4.0.0 http://maven.apache.org/maven-v4_0_0.xsd">
    <modelVersion>4.0.0</modelVersion>

    <groupId>org.jooq</groupId>
    <artifactId>jooq-webservices</artifactId>
    <packaging>war</packaging>
    <version>1.0</version>

    <build>
        <plugins>
            <plugin>
                <groupId>org.apache.maven.plugins</groupId>
                <artifactId>maven-compiler-plugin</artifactId>
                <version>2.0.2</version>
                <configuration>
                    <source>1.7</source>
                    <target>1.7</target>
                </configuration>
            </plugin>

            <plugin>
                <groupId>org.mortbay.jetty</groupId>
                <artifactId>maven-jetty-plugin</artifactId>
                <version>6.1.26</version>
                <configuration>
                    <reload>manual</reload>
                    <stopKey>stop</stopKey>
                    <stopPort>9966</stopPort>
                </configuration>
            </plugin>
            
            <plugin>
                <!-- Use org.jooq            for the Open Source Edition
                         org.jooq.pro        for commercial editions, 
                         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. 
                           Import the others manually from your distribution -->
                <groupId>org.jooq</groupId>
                <artifactId>jooq-codegen-maven</artifactId>
                <version>3.11.7</version>

                <!-- See GitHub for details -->
            </plugin>
        </plugins>
    </build>

    <dependencies>
        <dependency>
            <groupId>com.sun.jersey</groupId>
            <artifactId>jersey-server</artifactId>
            <version>1.0.2</version>
        </dependency>
        <dependency>
            <groupId>com.sun.jersey</groupId>
            <artifactId>jersey-json</artifactId>
            <version>1.0.2</version>
        </dependency>
        <dependency>
            <groupId>com.sun.jersey.contribs</groupId>
            <artifactId>jersey-spring</artifactId>
            <version>1.0.2</version>
        </dependency>
        <dependency>
            <groupId>javax.servlet</groupId>
            <artifactId>servlet-api</artifactId>
            <version>2.5</version>
        </dependency>
        
        <dependency>
            <!-- Use org.jooq            for the Open Source Edition
                     org.jooq.pro        for commercial editions, 
                     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. 
                       Import the others manually from your distribution -->
            <groupId>org.jooq</groupId>
            <artifactId>jooq</artifactId>
            <version>3.11.7</version>
        </dependency>
        <dependency>
            <groupId>org.postgresql</groupId>
            <artifactId>postgresql</artifactId>
            <version>9.4.1212</version>
        </dependency>
        <dependency>
            <groupId>log4j</groupId>
            <artifactId>log4j</artifactId>
            <version>1.2.16</version>
        </dependency>
    </dependencies>
</project>

With the above setup, we're now pretty ready to start developing our license service as a JAX-RS service.

The license service class

Once we've run the jOOQ code generator using Maven, we can write the following service class:

/**
 * The license server.
 */
@Path("/license/")
@Component
@Scope("request")
public class LicenseService {

    /**
     * <code>/license/generate</code> generates and returns a new license key.
     *
     * @param mail The input email address of the licensee.
     */
    @GET
    @Produces("text/plain")
    @Path("/generate")
    public String generate(
        final @QueryParam("mail") String mail
    ) {
        return run(new CtxRunnable() {
            
            @Override
            public String run(DSLContext ctx) {
                Timestamp licenseDate = new Timestamp(System.currentTimeMillis());
                
                // Use the jOOQ query DSL API to generate a license key
                return
                ctx.insertInto(LICENSE)
                   .set(LICENSE.LICENSE_, generateKey(inline(licenseDate), inline(mail)))
                   .set(LICENSE.LICENSE_DATE, licenseDate)
                   .set(LICENSE.LICENSEE, mail)
                   .returning()
                   .fetchOne()
                   .getLicense();
            }
        });
    }
    
    /**
     * <code>/license/verify</code> checks if a given licensee has access to version using a license.
     *
     * @param request The servlet request from the JAX-RS context.
     * @param mail The input email address of the licensee.
     * @param license The license used by the licensee.
     * @param version The product version being accessed.
     */
    @GET
    @Produces("text/plain")
    @Path("/verify")
    public String verify(
        final @Context HttpServletRequest request,
        final @QueryParam("mail") String mail,
        final @QueryParam("license") String license,
        final @QueryParam("version") String version
    ) {
        return run(new CtxRunnable() {
            @Override
            public String run(DSLContext ctx) {
                String v = (version == null || version.equals("")) ? "" : version;
                
                // Use the jOOQ query DSL API to generate a log entry
                return
                ctx.insertInto(LOG_VERIFY)
                   .set(LOG_VERIFY.LICENSE, license)
                   .set(LOG_VERIFY.LICENSEE, mail)
                   .set(LOG_VERIFY.REQUEST_IP, request.getRemoteAddr())
                   .set(LOG_VERIFY.MATCH, field(
                           selectCount()
                          .from(LICENSE)
                          .where(LICENSE.LICENSEE.eq(mail))
                          .and(LICENSE.LICENSE_.eq(license))
                          .and(val(v).likeRegex(LICENSE.VERSION))
                          .asField().gt(0)))
                   .set(LOG_VERIFY.VERSION, v)
                   .returning(LOG_VERIFY.MATCH)
                   .fetchOne()
                   .getValue(LOG_VERIFY.MATCH, String.class);
            }
        });
    }
    
    // [...]
}

The INSERT INTO LOG_VERIFY query is actually rather interesting. In plain SQL, it would look like this:

INSERT INTO LOG_VERIFY (LICENSE, LICENSEE, REQUEST_IP, MATCH, VERSION)
VALUES (
  :license,
  :mail,
  :remoteAddr,
  (SELECT COUNT(*) FROM LICENSE WHERE LICENSEE = :mail AND LICENSE = :license AND :version ~ VERSION) > 0,
  :version
)
RETURNING MATCH;

Apart from the foregoing, the LicenseService also contains a couple of simple utilities:

    /**
     * This method encapsulates a transaction and initialises a jOOQ DSLcontext.
     * This could also be achieved with Spring and DBCP for connection pooling.
     */
    private String run(CtxRunnable runnable) {
        try (Connection c = getConnection("jdbc:postgresql:postgres", "postgres", System.getProperty("pw", "test"))) {
            DSLContext ctx = DSL.using(new DefaultConfiguration()
                    .set(new DefaultConnectionProvider(c))
                    .set(SQLDialect.POSTGRES)
                    .set(new Settings().withExecuteLogging(false)));
            
            return runnable.run(ctx);
        }
        catch (Exception e) {
            e.printStackTrace();
            Response.status(Status.SERVICE_UNAVAILABLE);
            return "Service Unavailable - Please contact support@datageekery.com for help";
        }
    }
    
    private interface CtxRunnable {
        String run(DSLContext ctx);
    }

Configuring Spring and Jetty

All we need now is to configure Spring...

<beans xmlns="http://www.springframework.org/schema/beans"
    xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
    xmlns:context="http://www.springframework.org/schema/context"
    xsi:schemaLocation="
http://www.springframework.org/schema/beans http://www.springframework.org/schema/beans/spring-beans-2.5.xsd
http://www.springframework.org/schema/context http://www.springframework.org/schema/context/spring-context-2.5.xsd">

    <context:component-scan base-package="org.jooq.example.jaxrs" />

</beans>

... and Jetty ...

<?xml version="1.0" encoding="UTF-8"?>
<web-app version="2.4" xmlns="http://java.sun.com/xml/ns/j2ee"
    xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance"
    xsi:schemaLocation="http://java.sun.com/xml/ns/j2ee http://java.sun.com/xml/ns/j2ee/web-app_2_4.xsd">

    <context-param>
        <param-name>contextConfigLocation</param-name>
        <param-value>classpath:applicationContext.xml</param-value>
    </context-param>
    <listener>
        <listener-class>org.springframework.web.context.ContextLoaderListener</listener-class>
    </listener>
    <listener>
        <listener-class>org.springframework.web.context.request.RequestContextListener</listener-class>
    </listener>
    <servlet>
        <servlet-name>Jersey Spring Web Application</servlet-name>
        <servlet-class>com.sun.jersey.spi.spring.container.servlet.SpringServlet</servlet-class>
    </servlet>
    <servlet-mapping>
        <servlet-name>Jersey Spring Web Application</servlet-name>
        <url-pattern>/*</url-pattern>
    </servlet-mapping>
</web-app>

... and we're done! We can now run the server with the following command:

mvn jetty:run

Or if you need a custom port:

mvn jetty:run -Djetty.port=8088

Using the license server

You can now use the license server at the following URLs

http://localhost:8088/jooq-jax-rs-example/license/generate?mail=test@example.com
-> license-key

http://localhost:8088/jooq-jax-rs-example/license/verify?mail=test@example.com&license=license-key&version=3.2.0
-> true

http://localhost:8088/jooq-jax-rs-example/license/verify?mail=test@example.com&license=wrong&version=3.2.0
-> false

Let's verify what happened, in the database:

select * from license_server.license
-- id | license_date            | licensee         | license     | version
--------------------------------------------------------------------------
--  3 | 2013-11-22 14:26:07.768 | test@example.com | license-key | .*

select * from license_server.log_verify
-- id | licensee         | license     | request_ip      | version | match
--------------------------------------------------------------------------
--  2 | test@example.com | license-key | 0:0:0:0:0:0:0:1 | 3.2.0   | t
--  5 | test@example.com | wrong       | 0:0:0:0:0:0:0:1 | 3.2.0   | f

Downloading the complete example

The complete example can be downloaded for free and under the terms of the Apache Software License 2.0 from here:
https://github.com/jOOQ/jOOQ/tree/master/jOOQ-examples/jOOQ-jax-rs-example

Feel free to contribute a tutorial!

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: http://blog.jooq.org/2014/04/11/java-8-friday-no-more-need-for-orms/. For more information about Java 8, consider these resources:

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 nested SELECT, 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/master/jOOQ-examples/jOOQ-javafx-example

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()
);

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.

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.

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.

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), SOQL (Salesforce 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.

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

Dependencies are a big hassle in modern software. Many libraries depend on other, non-JDK library parts that come in different, incompatible versions, potentially causing trouble in your runtime environment. jOOQ has no external dependencies on any third-party libraries.

However, the above rule has some exceptions:

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

Semantic versioning

jOOQ's understanding of backwards compatibility is inspired by the rules of semantic versioning according to http://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

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).
  • 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.
  • 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.

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.

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));

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)

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:

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();

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

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).

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 J2EE 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. An example of using DataSources with jOOQ can be seen in the tutorial section about using jOOQ with Spring.

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;
}

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:

// Implement an ExecuteListener
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.

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.

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:
http://www.jooq.org/xsd/jooq-runtime-3.11.2.xsd

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.

Programmatic configuration

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

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.11.2.xsd">
  <renderCatalog>false</renderCatalog>
  <renderSchema>false</renderSchema>
</settings>

By turning off the rendering of full qualification as can be seen above, it will be possible to use code generated from one schema on an entirely different schema of the same structure, e.g. for multitenancy purposes.

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

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:

Programmatic 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.11.2.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:

Programmatic 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.11.2.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. If you omit a MappedSchema's input value, the table mapping is applied to all schemata!

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:

Programmatic 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.11.2.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 schema mappings at code generation time

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.11.2.xsd">
  <renderNameStyle>AS_IS</renderNameStyle>
</settings>

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.
  • PASCAL: Generate keywords in pascal 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.11.2.xsd">
  <renderKeywordStyle>UPPER</renderKeywordStyle>
</settings>

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.11.2.xsd">
  <paramType>NAMED</paramType>
</settings>

The following setting statementType may override this setting.

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.11.2.xsd">
  <statementType>STATIC_STATEMENT</statementType>
</settings>

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.11.2.xsd">
  <executeLogging>false</executeLogging>
</settings>

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.11.2.xsd">
  <executeWithOptimisticLocking>true</executeWithOptimisticLocking>
  <executeWithOptimisticLockingExcludeUnversioned>false</executeWithOptimisticLockingExcludeUnversioned>
</settings>

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

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.11.2.xsd">
  <attachRecords>false</attachRecords>
</settings>

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.11.2.xsd">
  <updatablePrimaryKeys>true</updatablePrimaryKeys>
</settings>

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.11.2.xsd">
  <reflectionCaching>false</reflectionCaching>
</settings>

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.11.2.xsd">
  <fetchWarnings>false</fetchWarnings>
</settings>

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.

Programmatic configuration

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

XML configuration

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

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.11.2.xsd">
  <mapJPAAnnotations>false</mapJPAAnnotations>
</settings>

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.11.2.xsd">
  <queryTimeout>5</queryTimeout>
  <maxRows>1000</maxRows>
  <fetchSize>20</fetchSize>
</settings>

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.11.2.xsd">
  <inListPadding>true</inListPadding>
</settings>

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.

Programmatic configuration

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

XML configuration

<settings xmlns="http://www.jooq.org/xsd/jooq-runtime-3.11.2.xsd">
  <backslashEscaping>OFF</backslashEscaping>
</settings>

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.

Programmatic configuration

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

XML configuration

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

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.

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 in modern IDEs with syntax 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.

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();

Recursive common table expressions

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.

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.

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));

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
Select<?> select1 = create.selectCount().fetch();
Select<?> select2 = create.selectZero().fetch();
Select<?> select2 = create.selectOne().fetch();

See more details about functions and expressions in the manual's section about Column expressions

The SELECT DISTINCT clause

The DISTINCT keyword can be included in the method name, constructing a SELECT clause

SELECT DISTINCT BOOK.TITLE
Select<?> select1 = create.selectDistinct(BOOK.TITLE).fetch();

SELECT *

jOOQ supports the asterisk operator in projections both as a qualified asterisk (through Table.asterisk()) and as an unqualified asterisk (through DSL.asterisk()). It is also possible to omit the projection entirely, in case of which an asterisk may appear in generated SQL, if not all column names are known to jOOQ.

// Explicitly selects all columns available from BOOK - No asterisk
create.select().from(BOOK).fetch();

// Explicitly selects all columns available from BOOK and AUTHOR - No asterisk
create.select().from(BOOK, AUTHOR).fetch();
create.select().from(BOOK).crossJoin(AUTHOR).fetch();

// Renders a SELECT * statement, as columns are unknown to jOOQ - Implicit unqualified asterisk
create.select().from(table(name("BOOK"))).fetch();

// Renders a SELECT * statement - Explicit unqualified asterisk
create.select(asterisk()).from(BOOK).fetch();

// Renders a SELECT BOOK.* statement - Explicit qualified asterisk
create.select(BOOK.asterisk()).from(BOOK).fetch();
create.select(BOOK.asterisk(), AUTHOR.asterisk()).from(BOOK, AUTHOR).fetch();

With all of the above syntaxes, the row type (as discussed below) is unknown to jOOQ and to the Java compiler.

It is worth mentioning that in many cases, using an asterisk is a sign of an inefficient query because if not all columns are needed, too much data is transferred between client and server, plus some joins that could be eliminated otherwise, cannot.

Typesafe projections with degree up to 22

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 Field<?>> fields);
public static SelectSelectStep<Record> select(Field<?>... fields);

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

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));

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

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:

jOOQ supports many different types of standard and non-standard SQL JOIN operations:

  • [ INNER ] JOIN
  • LEFT [ OUTER ] JOIN
  • RIGHT [ OUTER ] JOIN
  • FULL OUTER JOIN
  • LEFT SEMI JOIN
  • LEFT ANTI JOIN
  • CROSS JOIN
  • NATURAL JOIN
  • NATURAL LEFT [ OUTER ] JOIN
  • NATURAL RIGHT [ OUTER ] JOIN

Besides, jOOQ also supports

  • CROSS APPLY (T-SQL and Oracle 12c specific)
  • OUTER APPLY (T-SQL and Oracle 12c specific)
  • LATERAL derived tables (PostgreSQL and Oracle 12c)
  • partitioned outer join

All of these JOIN methods can be called on org.jooq.Table types, 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();

JOIN ON KEY, convenience provided by jOOQ

Surprisingly, the SQL standard does not allow to formally JOIN on well-known foreign key relationship information. Naturally, when you join BOOK to AUTHOR, you will want to do that based on the BOOK.AUTHOR_ID foreign key to AUTHOR.ID primary key relation. Not being able to do this in SQL leads to a lot of repetitive code, re-writing the same JOIN predicate again and again - especially, when your foreign keys contain more than one column. With jOOQ, when you use code generation, you can use foreign key constraint information in JOIN expressions as such:

SELECT *
FROM AUTHOR
JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
 
create.select()
      .from(AUTHOR)
      .join(BOOK).onKey()
      .fetch();

In case of ambiguity, you can also supply field references for your foreign keys, or the generated foreign key reference to the onKey() method.

Note that formal support for the Sybase JOIN ON KEY syntax is on the roadmap.

The JOIN USING syntax

Most often, you will provide jOOQ with JOIN conditions in the JOIN .. ON clause. SQL supports a different means of specifying how two tables are to be joined. This is the JOIN .. USING clause. Instead of a condition, you supply a set of fields whose names are common to both tables to the left and right of a JOIN operation. This can be useful when your database schema has a high degree of relational normalisation. An example:

-- Assuming that both tables contain AUTHOR_ID columns
SELECT *
FROM AUTHOR
JOIN BOOK USING (AUTHOR_ID)
 
// join(...).using(...)
create.select()
      .from(AUTHOR)
      .join(BOOK).using(AUTHOR.AUTHOR_ID)
      .fetch();

In schemas with high degrees of normalisation, you may also choose to use NATURAL JOIN, which takes no JOIN arguments as it joins using all fields that are common to the table expressions to the left and to the right of the JOIN operator. An example:

-- Assuming that both tables contain AUTHOR_ID columns
SELECT *
FROM AUTHOR
NATURAL JOIN BOOK
 
// naturalJoin(...)
create.select()
      .from(AUTHOR)
      .naturalJoin(BOOK)
      .fetch();

Oracle's partitioned OUTER JOIN

Oracle SQL ships with a special syntax available for OUTER JOIN clauses. According to the Oracle documentation about partitioned outer joins 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();

SEMI JOIN and ANTI JOIN

Very few databases (e.g. Apache Impala) ship with a built-in syntax for { LEFT | RIGHT } SEMI JOIN and { LEFT | RIGHT } ANTI JOIN, which are much more concise versions of the SQL standard IN / EXISTS and NOT IN / NOT EXISTS predicates. The idea is that the JOIN syntax is expressed where it belongs, in the FROM clause, not in the WHERE clause.

Since jOOQ 3.7, these types of JOIN are also supported and they're emulated using EXISTS and NOT EXISTS respectively.

Here's how SEMI JOIN translates to EXISTS.

SELECT FIRST_NAME, LAST_NAME
FROM AUTHOR
WHERE EXISTS (
  SELECT 1 FROM BOOK WHERE AUTHOR.ID = BOOK.AUTHOR_ID
)
create.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .leftSemiJoin(BOOK)
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

And here's how ANTI JOIN translates to NOT EXISTS

SELECT FIRST_NAME, LAST_NAME
FROM AUTHOR
WHERE NOT EXISTS (
  SELECT 1 FROM BOOK WHERE AUTHOR.ID = BOOK.AUTHOR_ID
)
create.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .leftAntiJoin(BOOK)
      .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      .fetch();

T-SQL's CROSS APPLY and OUTER APPLY

T-SQL has long known what the SQL standard calls lateral derived tables, lateral joins using the APPLY keyword. To every row resulting from the table expression on the left, we apply the table expression on the right. This is extremely useful for table-valued functions, which are also supported by jOOQ. Some examples:

DSL.using(configuration)
   .select()
   .from(AUTHOR,
         lateral(select(count().as("c"))
                .from(BOOK)
                .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
   )
   .fetch("c", int.class);

The above example shows standard usage of the LATERAL keyword to connect a derived table to the previous table in the FROM clause. A similar statement can be written in T-SQL:

DSL.using(configuration)
   .from(AUTHOR)
   .crossApply(
       select(count().as("c"))
      .from(BOOK)
      .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
   )
   .fetch("c", int.class)

While not all forms of LATERAL JOIN have an equivalent APPLY syntax, the inverse is true, and jOOQ can thus emulate OUTER APPLY and CROSS APPLY using LATERAL JOIN.

LATERAL JOIN or CROSS APPLY are particularly useful together with table valued functions, which are also supported by jOOQ.

In SQL, a lot of explicit JOIN clauses are written simply to retrieve a parent table's column from a given child table. For example, we'll write:

-- Get all books, their authors, and their respective language
SELECT 
  a.first_name, 
  a.last_name, 
  b.title, 
  l.cd AS language
FROM book b
JOIN author a ON b.author_id = a.id
JOIN language l ON b.language_id = l.id;

-- Count the number of books by author and language
SELECT 
  a.first_name, 
  a.last_name, 
  l.cd AS language, 
  COUNT(*)
FROM book
JOIN author a ON b.author_id = a.id
JOIN language l ON b.language_id = l.id
GROUP BY a.id, a.first_name, a.last_name, l.cd
ORDER BY a.first_name, a.last_name, l.cd

There is quite a bit of syntactic ceremony (or we could even call it "noise") to get a relatively simple job done. A much simpler notation would be using implicit joins:

-- Get all books, their authors, and their respective language
SELECT 
  b.author.first_name, 
  b.author.last_name, 
  b.title, 
  b.language.cd AS language
FROM book b;

-- Count the number of books by author and language
SELECT 
  b.author.first_name, 
  b.author.last_name, 
  b.language.cd AS language, 
  COUNT(*)
FROM book
GROUP BY 
  b.author_id, 
  b.author.first_name, 
  b.author.last_name, 
  b.language.cd
ORDER BY 
  b.author.first_name, 
  b.author.last_name, 
  b.language.cd

Notice how this alternative notation (depending on your taste) may look more tidy and straightforward, as the semantics of accessing a table's parent table (or an entity's parent entity) is straightforward.

From jOOQ 3.11 onwards, this syntax is supported for to-one relationship navigation. The code generator produces relevant navigation methods on generated tables, which can be used in a type safe way. The navigation method names are:

  • The parent table name, if there is only one foreign key between child table and parent table
  • The foreign key name, if there are more than one foreign keys between child table and parent table

This default behaviour can be overridden by using a Code Generator Strategy.

The jOOQ version of the previous queries looks like this:

// Get all books, their authors, and their respective language
create.select(
          BOOK.author().FIRST_NAME,
          BOOK.author().LAST_NAME,
          BOOK.TITLE,
          BOOK.language().CD.as("language"))
      .from(BOOK)
      .fetch();
             
// Count the number of books by author and language
create.select(
          BOOK.author().FIRST_NAME,
          BOOK.author().LAST_NAME,
          BOOK.language().CD.as("language"),
          count())
      .from(BOOK)
      .groupBy(
          BOOK.AUTHOR_ID,
          BOOK.author().FIRST_NAME,
          BOOK.author().LAST_NAME,
          BOOK.language().CD)
      .orderBy(
          BOOK.author().FIRST_NAME,
          BOOK.author().LAST_NAME,
          BOOK.language().CD)
      .fetch();

The generated SQL is almost identical to the original one - there is no performance penalty to this syntax.

How it works

During the SQL generation phase, implicit join paths are replaced by generated aliases for the path's last table. The paths are translated to a join graph, which is always LEFT JOINed to the path's "root table". If two paths share a common prefix, that prefix is also shared in the join graph.

Future versions of jOOQ may choose to generate correlated subqueries or inner joins where this may seem more appropriate, if the query semantics doesn't change through that.

Known limitations

  • Implicit JOINs are currently only supported in SELECT statements (including any type of subquery), but not in the WHERE clause of UPDATE statements or DELETE statements, for instance.
  • Implicit JOINs can currently only be used to access columns, not to produce joins. I.e. it is not possible to write things like FROM book IMPLICIT JOIN book.author
  • Implicit JOINs are added to the SQL string after the entire SQL statement is available, for performance reasons. This means, that VisitListener SPI implementations cannot observe implicitly joined tables

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.

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(
   sysConnectByPath(DIRECTORY.NAME, "/").substring(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

Note that this syntax is also supported in the CUBRID database and might be emulated in other dialects supporting common table expressions in the future.

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();

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. For instance, you can group books by BOOK.AUTHOR_ID:

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, as defined in the SQL standard, when grouping, you may no longer project any columns that are not a formal part of the GROUP BY clause, or aggregate functions.

Empty GROUP BY clauses

jOOQ supports empty GROUP BY () clause as well. This will result in SELECT statements that return only one record.

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

ROLLUP(), CUBE() and GROUPING SETS()

Some databases support the SQL standard grouping functions and some extensions thereof. See the manual's section about grouping functions for more details.

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();

The SQL:2003 standard as well as PostgreSQL and Sybase SQL Anywhere support 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));
 
 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: http://blog.jooq.org/2013/11/03/probably-the-coolest-sql-feature-window-functions/

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

While being extremely useful for every application that does pagination, or just to limit result sets to reasonable sizes, this clause is not yet part of any SQL standard (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).limit(1).offset(2).fetch();

This will limit the result to 1 books starting with the 2nd book (starting at offset 0!). 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 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 OFFSET 2 ROWS FETCH NEXT 1 ROWS ONLY

-- Informix has SKIP .. FIRST support
SELECT SKIP 2 FIRST 1 * FROM BOOK

-- Ingres (almost the SQL:2008 standard)
SELECT * FROM BOOK OFFSET 2 FETCH FIRST 1 ROWS ONLY

-- Firebird
SELECT * FROM BOOK ROWS 2 TO 3

-- Sybase SQL Anywhere
SELECT TOP 1 ROWS START AT 3 * FROM BOOK

-- DB2 (almost the SQL:2008 standard, without OFFSET)
SELECT * FROM BOOK FETCH FIRST 1 ROWS ONLY

-- Sybase ASE, SQL Server 2008 (without OFFSET)
SELECT TOP 1 * FROM BOOK

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.

Side-note: If you're interested in understanding why we chose ROWNUM for Oracle, please refer to this very interesting benchmark, comparing the different approaches of doing pagination in Oracle: http://www.inf.unideb.hu/~gabora/pagination/results.html.

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.

The previous chapter talked about the LIMIT clause, which limits the result set to a certain number of rows. The SQL standard specifies the following syntax:

OFFSET m { ROW | ROWS }
FETCH { FIRST | NEXT } n { ROW | ROWS } { ONLY | WITH TIES }

By default, most users will use the semantics of the ONLY keyword, meaning a LIMIT 5 expression (or FETCH NEXT 5 ROWS ONLY expression) will result in at most 5 rows. The alternative clause WITH TIES will return at most 5 rows, except if the 5th row and the 6th row (and so on) are "tied" according to the ORDER BY clause, meaning that the ORDER BY clause does not deterministically produce a 5th or 6th row. For example, let's look at our book table:

SELECT * 
FROM book 
ORDER BY actor_id 
FETCH NEXT 1 ROWS WITH TIES
DSL.using(configuration)
   .selectFrom(BOOK)
   .orderBy(BOOK.ACTOR_ID)
   .limit(1).withTies()
   .fetch();

Resulting in:

id   actor_id   title
---------------------
1    1          1984
2    1          Animal Farm

We're now getting two rows because both rows "tied" when ordering them by ACTOR_ID. The database cannot really pick the next 1 row, so they're both returned. If we omit the WITH TIES clause, then only a random one of the rows would be returned.

Not all databases support WITH TIES. Oracle 12c supports the clause as specified in the SQL standard, and SQL Server knows TOP n WITH TIES without OFFSET support.

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. 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(2, 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:

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.

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.

UNION and UNION ALL

These operators combine two results into one. 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. 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();

INTERSECT [ ALL ] and EXCEPT [ ALL ]

INTERSECT is the operation that produces only those values that are returned by both subselects. EXCEPT (or MINUS in Oracle) is the operation that returns only those values that are returned exclusively in the first subselect. Both operators will remove duplicates from their results.

Just like with UNION ALL, these operators have an optional ALL keyword that allows for keeping duplicate rows after intersection or subtraction, which is supported in jOOQ 3.7+.

jOOQ's set operators and how they're different from standard SQL

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 subselect may not contain any ORDER BY clause or LIMIT clause (unless you wrap the subselect into a nested SELECT), 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

Projection typesafety for degrees between 1 and 22

Two subselects 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

If you are closely coupling your application to an Oracle (or CUBRID) database, you might need to be able to pass hints of the form /*+HINT*/ with your SQL statements to the Oracle database. For example:

SELECT /*+ALL_ROWS*/ FIRST_NAME, LAST_NAME
  FROM AUTHOR

This can be done in jOOQ using the .hint() clause in your SELECT statement:

create.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .hint("/*+ALL_ROWS*/")
      .from(AUTHOR)
      .fetch();

Note that you can pass any string in the .hint() clause. If you use that clause, the passed string will always be put in between the SELECT [DISTINCT] keywords and the actual projection list. This can be useful in other databases too, such as MySQL, for instance:

SELECT SQL_CALC_FOUND_ROWS field1, field2
FROM table1

 
create.select(field1, field2)
      .hint("SQL_CALC_FOUND_ROWS")
      .from(table1)
      .fetch()

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.

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.

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();

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.

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.

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();

The synthetic 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 (i.e. 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();

The synthetic ON DUPLICATE KEY IGNORE clause

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:

Emulating IGNORE with MERGE

The above jOOQ statement can be emulated with the following, equivalent SQL statement:

MERGE INTO AUTHOR
USING (SELECT 1 FROM DUAL)
ON (AUTHOR.ID = 3)
WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME)
  VALUES (3, 'Koontz')

Emulating IGNORE with INSERT .. SELECT WHERE NOT EXISTS

The above jOOQ statement can be emulated with the following, equivalent SQL statement:

INSERT INTO AUTHOR (ID, LAST_NAME)
SELECT 3, 'Koontz'
WHERE NOT EXISTS (
  SELECT 1
  FROM AUTHOR
  WHERE AUTHOR.ID = 3
)

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.

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 will be implemented in the near 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();

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:

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();

Using row value expressions in an UPDATE statement

jOOQ supports formal row value expressions in various contexts, among which the UPDATE statement. Only one row value expression can be updated at a time. Here's an example:

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 subselects:

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.

UPDATE .. FROM

Some databases, including 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.

UPDATE .. RETURNING

The Firebird and Postgres databases support a RETURNING clause 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);

The UPDATE .. RETURNING clause is emulated for DB2 using the SQL standard SELECT .. FROM FINAL TABLE(UPDATE ..) construct, and in Oracle, using the PL/SQL UPDATE .. RETURNING statement.

The DELETE statement removes records from a database table. DELETE statements are only possible on single tables. Support for multi-table deletes will be implemented in the near future. An example delete query is given here:

DELETE AUTHOR
 WHERE ID = 100;
 
create.delete(AUTHOR)
      .where(AUTHOR.ID.eq(100))
      .execute();

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.11.7, 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:
http://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.

jOOQ's DDL support is currently still very limited. In the long run, jOOQ will support the most important statement types for frequent informal database migrations, though. Note that jOOQ will not aim to replace existing database migration frameworks. At Data Geekery, we usually recommend using Flyway for migrations. See also the tutorial about using jOOQ with Flyway for more information.

Most databases support a variety of SET statements to set session specific environment variables. jOOQ supports two of these set statements that are particularly useful when running DDL scripts:

SET CATALOG catalogname;
SET SCHEMA schemaname;
create.setCatalog("catalogname").execute();
create.setSchema("schemaname").execute();

Depending on whether your database supports catalogs and schemas, the above SET statements may be supported in your database.

In MariaDB, MySQL, SQL Server, the SET CATALOG statement is emulated using:

USE catalogname;

In Oracle, the SET SCHEMA statement is emulated using:

ALTER SESSION SET CURRENT_SCHEMA = schemaname;

jOOQ currently supports the following ALTER statements (SQL examples in PostgreSQL syntax):

Indexes

// Renaming the index
create.alterIndex("old_index").renameTo("new_index").execute();

// Renaming the index only if it exists (not all databases support this)
create.alterIndexIfExists("old_index").renameTo("new_index").execute();

Schemas

// Renaming the schema
create.alterSchema("old_schema").renameTo("new_schema").execute();

// Renaming the schema only if it exists (not all databases support this)
create.alterSchemaIfExists("old_schema").renameTo("new_schema").execute();

Sequences

// Renaming the sequence
create.alterSequence("old_sequence").renameTo("new_sequence").execute();

// Renaming the sequence only if it exists (not all databases support this)
create.alterSequenceIfExists("old_sequence").renameTo("new_sequence").execute();

// Restarting the sequence
create.alterSequence(S_AUTHOR_ID).restart().execute();
create.alterSequence(S_AUTHOR_ID).restartWith(n).execute();

Tables

These statements alter the table itself:

// Renaming the table
create.alterTable("old_table").renameTo("new_table").execute();

// Renaming the table only if it exists (not all databases support this)
create.alterTableIfExists("old_table").renameTo("new_table").execute();

These statements alter / add / drop columns and their types:

// Adding columns
create.alterTable(AUTHOR).add(AUTHOR.TITLE, VARCHAR.length(5)).execute();
create.alterTable(AUTHOR).add(AUTHOR.TITLE, VARCHAR.length(5).nullable(false)).execute();

// Altering columns
create.alterTable(AUTHOR).alter(TITLE).defaultValue("no title").execute();
create.alterTable(AUTHOR).alter(TITLE).set(VARCHAR.length(5)).execute();
create.alterTable(AUTHOR).alter(TITLE).set(VARCHAR.length(5).nullable(false)).execute();
create.alterTable(AUTHOR).renameColumn("old_column").to("new_column").execute();

// Dropping columns
create.alterTable(AUTHOR).drop(TITLE).execute();

These statements alter / add / drop constraints:

// Adding constraints
create.alterTable(BOOK).add(constraint("PK_BOOK").primaryKey(BOOK.ID)).execute();
create.alterTable(BOOK).add(constraint("UK_TITLE").unique(BOOK.TITLE)).execute();
create.alterTable(BOOK).add(
   constraint("FK_AUTHOR_ID")
  .foreignKey(BOOK.AUTHOR_ID)
  .references(AUTHOR, AUTHOR.ID)).execute();
create.alterTable(BOOK).add(
   constraint("CHECK_PUBLISHED_IN")
  .check(BOOK.PUBLISHED_IN.between(1900).and(2000))).execute();

// Altering constraints
create.alterTable(BOOK).renameConstraint("old_constraint").to("new_constraint").execute();

// Dropping constraints
create.alterTable(AUTHOR).dropConstraint("UK_TITLE").execute();

Views

// Renaming the view
create.alterView("old_view").renameTo("new_view").execute();

// Renaming the view only if it exists (not all databases support this)
create.alterViewIfExists("old_view").renameTo("new_view").execute();

jOOQ currently supports the following CREATE statements (SQL examples in PostgreSQL syntax):

Indexes

// Create a non-unique index
create.createIndex("I_AUTHOR_LAST_NAME").on(AUTHOR, AUTHOR.LAST_NAME).execute();

// Create an index only if it doesn't exist (not all databases support this)
create.createIndexIfNotExists("I_AUTHOR_LAST_NAME").on(AUTHOR, AUTHOR.LAST_NAME).execute();

// Create a partial index (not all databases support this)
create.createIndex("I_AUTHOR_LAST_NAME").on(AUTHOR, AUTHOR.LAST_NAME).where(AUTHOR.LAST_NAME.like("A%")).execute();

// Create a unique index
create.createUniqueIndex("I_AUTHOR_LAST_NAME").on(AUTHOR, AUTHOR.LAST_NAME).execute();

Schemas

// Create a schema
create.createSchema("new_schema").execute();

// Create a schema only if it doesn't exists (not all databases support this)
create.createSchemaIfNotExists("new_schema").execute();

Sequences

// Create a sequence
create.createSequence(S_AUTHOR_ID).execute();

// Create a sequence only if it doesn't exists (not all databases support this)
create.createSequence(S_AUTHOR_ID).execute();

Tables

// Creating a table with columns and inline constraints
create.createTable(AUTHOR)
      .column(AUTHOR.ID, SQLDataType.INTEGER)
      .column(AUTHOR.FIRST_NAME, SQLDataType.VARCHAR.length(50).nullable(false))
      .column(AUTHOR.LAST_NAME, SQLDataType.VARCHAR.length(50))
      .constraints(
          constraint("PK_AUTHOR").primaryKey(AUTHOR.ID),
          constraint("UK_AUTHOR").unique(FIRST_NAME, LAST_NAME))
      .execute();

// Creating a table from a SELECT statement
create.createTable("TOP_AUTHORS").as(
       select(
         AUTHOR.ID,
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .where(val(50).lt(
         selectCount().from(BOOK)
        .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      ))).execute();
      
// Create a table only if it doesn't exists (not all databases support this)
create.createTableIfNotExists("TOP_AUTHORS")
      ...

Views

// Create a view
create.createView("V_TOP_AUTHORS").as(
       select(
         AUTHOR.ID,
         AUTHOR.FIRST_NAME,
         AUTHOR.LAST_NAME)
      .from(AUTHOR)
      .where(val(50).lt(
         selectCount().from(BOOK)
        .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
      ))).execute();
      
// Create a view only if it doesn't exists (not all databases support this)
create.createTableIfNotExists("TOP_AUTHORS")
      ...

jOOQ currently supports the following DROP statements (SQL examples in PostgreSQL syntax):

Indexes

// Drop an index
create.dropIndex("I_AUTHOR_LAST_NAME").execute();

// Drop an index only if it exists (not all databases support this)
create.dropIndexIfExists("I_AUTHOR_LAST_NAME").execute();

Schemas

// Drop a schema
create.dropSchema("schema").execute();

// Drop a schema only if it exists (not all databases support this)
create.dropSchemaIfExists("schema").execute();

Sequences

// Drop a sequence
create.dropSequence(S_AUTHOR_ID).execute();

// Drop a sequence only if it exists (not all databases support this)
create.dropSequenceIfExists(S_AUTHOR_ID).execute();

Tables

// Drop a table
create.dropTable(AUTHOR).execute();

// Drop a table only if it exists (not all databases support this)
create.dropTableIfExists(AUTHOR).execute();

Views

// Drop a view
create.dropView(V_AUTHOR).execute();

[// Drop a view only if it exists (not all databases support this)
create.dropViewIfExists(V_AUTHOR).execute();

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 Ingres and SQLite. jOOQ will execute a DELETE FROM AUTHOR statement instead.

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"."T_AUTHOR"(
  "ID" int not null,
  "FIRST_NAME" varchar(50) null,
  "LAST_NAME" varchar(50) not null,
  ...
  constraint "PK_T_AUTHOR"
    primary key ("ID")
)
create table "PUBLIC"."T_BOOK"(
  "ID" int not null,
  "AUTHOR_ID" int not null,
  "TITLE" varchar(400) not null,
  ...
  constraint "PK_T_BOOK"
    primary key ("ID")
)
...
alter table "PUBLIC"."T_BOOK"
  add constraint "FK_T_BOOK_AUTHOR_ID"
    foreign key ("AUTHOR_ID")
    references "T_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.

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, which allows 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]

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

The following sections explain the various types of table expressions supported by jOOQ

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

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.

Dereferencing columns from other table expressions

Only few table expressions provide the SQL syntax typesafety as shown above, where generated tables are used. Most tables, however, expose their fields through 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");

Derived column lists

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 (as supported by Postgres, for instance):

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();

Unnamed derived tables

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.

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. Informally, the following can be said:

A(colA1, ..., colAn) "join" B(colB1, ..., colBm) "produces" C(colA1, ..., colAn, colB1, ..., colBm)

SQL and relational algebra distinguish between at least the following JOIN types (upper-case: SQL, lower-case: relational algebra):

  • CROSS JOIN or cartesian product: The basic JOIN in SQL, producing a relational cross product, combining every record of table A with every record of table B. Note that cartesian products can also be produced by listing comma-separated table expressions in the FROM clause of a SELECT statement
  • NATURAL JOIN: The basic JOIN in relational algebra, yet a rarely used JOIN in databases with everyday degree of normalisation. This JOIN type unconditionally equi-joins two tables by all columns with the same name (requiring foreign keys and primary keys to share the same name). Note that the JOIN columns will only figure once in the resulting table expression.
  • INNER JOIN or equi-join: This JOIN operation performs a cartesian product (CROSS JOIN) with a filtering predicate being applied to the resulting table expression. Most often, a equal comparison predicate comparing foreign keys and primary keys will be applied as a filter, but any other predicate will work, too.
  • OUTER JOIN: This JOIN operation performs a cartesian product (CROSS JOIN) with a filtering predicate being applied to the resulting table expression. Most often, a equal comparison predicate comparing foreign keys and primary keys will be applied as a filter, but any other predicate will work, too. Unlike the INNER JOIN, an OUTER JOIN will add "empty records" to the left (table A) or right (table B) or both tables, in case the conditional expression fails to produce a .
  • semi-join: In SQL, this JOIN operation can only be expressed implicitly using IN predicates or EXISTS predicates. The table expression resulting from a semi-join will only contain the left-hand side table A
  • anti-join: In SQL, this JOIN operation can only be expressed implicitly using NOT IN predicates or NOT EXISTS predicates. The table expression resulting from a semi-join will only contain the left-hand side table A
  • division: This JOIN operation is hard to express at all, in SQL. See the manual's chapter about relational division for details on how jOOQ emulates this operation.

jOOQ supports all of these JOIN types (including semi-join and anti-join) directly on any table expression:

// jOOQ's relational division convenience syntax
DivideByOnStep divideBy(Table<?> table)

// INNER JOIN
TableOnStep join(TableLike<?>)
TableOnStep innerJoin(TableLike<?>)

// OUTER JOIN (supporting Oracle's partitioned OUTER JOIN)
TablePartitionByStep leftJoin(TableLike<?>)
TablePartitionByStep leftOuterJoin(TableLike<?>)

TablePartitionByStep rightJoin(TableLike<?>)
TablePartitionByStep rightOuterJoin(TableLike<?>)

// FULL OUTER JOIN
TableOnStep fullOuterJoin(TableLike<?>)

// SEMI JOIN
TableOnStep<R> leftSemiJoin(TableLike<?>);

// ANTI JOIN
TableOnStep<R> leftAntiJoin(TableLike<?>);

// CROSS JOIN
Table<Record> crossJoin(TableLike<?>)

// NATURAL JOIN
Table<Record> naturalJoin(TableLike<?>)
Table<Record> naturalLeftOuterJoin(TableLike<?>)
Table<Record> naturalRightOuterJoin(TableLike<?>)

Most of the above JOIN types are overloaded also to accommodate plain SQL use-cases for convenience:

// Standard overload accepting a formal jOOQ table reference
TableOnStep join(TableLike<?>)

// Overloaded versions taking SQL template strings with bind variables, or other forms of
// "plain SQL" QueryParts:
TableOnStep join(String)
TableOnStep join(String, Object...)
TableOnStep join(String, QueryPart...)
TableOnStep join(SQL)
TableOnStep join(Name)

Note that most of jOOQ's JOIN operations give way to a similar DSL API hierarchy as previously seen in the manual's section about the JOIN clause

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

A SELECT statement can appear almost anywhere a table expression can. Such a "nested SELECT" is often called a "derived table". Apart from many convenience methods accepting org.jooq.Select objects directly, a SELECT statement can always be transformed into a org.jooq.Table object using the asTable() method.

Example: Scalar subquery

SELECT *
  FROM BOOK
 WHERE BOOK.AUTHOR_ID = (
 		SELECT ID
          FROM AUTHOR
         WHERE LAST_NAME = 'Orwell')
 
create.select()
      .from(BOOK)
      .where(BOOK.AUTHOR_ID.eq(create
             .select(AUTHOR.ID)
             .from(AUTHOR)
             .where(AUTHOR.LAST_NAME.eq("Orwell"))))
      .fetch();

Example: Derived table

 

SELECT nested.* FROM (
      SELECT AUTHOR_ID, count(*) books
        FROM BOOK
    GROUP BY AUTHOR_ID
) nested
ORDER BY nested.books DESC
 
Table<Record> 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();

Example: Correlated subquery

 



SELECT LAST_NAME, (
      SELECT COUNT(*)
       FROM BOOK
      WHERE BOOK.AUTHOR_ID = AUTHOR.ID) books
    FROM AUTHOR
ORDER BY books DESC
 
// The type of books cannot be inferred from the Select<?>
Field<Object> books =
    create.selectCount()
          .from(BOOK)
          .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
          .asField("books");

create.select(AUTHOR.ID, books)
      .from(AUTHOR)
      .orderBy(books, AUTHOR.ID))
      .fetch();

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.

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

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.

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();

The SQL standard specifies that the FROM clause is optional in a SELECT statement. However, according to the standard, you may then no longer use some other clauses, such as the WHERE clause. 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

SELECT 1 FROM (SELECT COUNT(*) FROM MSysResources) AS dual
SELECT 1
SELECT 1 FROM "db_root"
SELECT 1 FROM "SYSIBM"."DUAL"
SELECT 1 FROM "SYSIBM"."SYSDUMMY1"
SELECT 1 FROM "RDB$DATABASE"
SELECT 1 FROM dual
SELECT 1 FROM "SYS"."DUMMY"
SELECT 1 FROM "INFORMATION_SCHEMA"."SYSTEM_USERS"
SELECT 1 FROM (SELECT 1 AS dual FROM systables WHERE tabid = 1)
SELECT 1 FROM (SELECT 1 AS dual) AS dual
SELECT 1 FROM dual
SELECT 1 FROM dual
SELECT 1 FROM dual
SELECT 1
SELECT 1
SELECT 1
SELECT 1 FROM [SYS].[DUMMY]
DSL.using(SQLDialect.ACCESS   ).selectOne().getSQL();
DSL.using(SQLDialect.ASE      ).selectOne().getSQL();
DSL.using(SQLDialect.CUBRID   ).selectOne().getSQL();
DSL.using(SQLDialect.DB2      ).selectOne().getSQL();
DSL.using(SQLDialect.DERBY    ).selectOne().getSQL();
DSL.using(SQLDialect.FIREBIRD ).selectOne().getSQL();
DSL.using(SQLDialect.H2       ).selectOne().getSQL();
DSL.using(SQLDialect.HANA     ).selectOne().getSQL();
DSL.using(SQLDialect.HSQLDB   ).selectOne().getSQL();
DSL.using(SQLDialect.INFORMIX ).selectOne().getSQL();
DSL.using(SQLDialect.INGRES   ).selectOne().getSQL();
DSL.using(SQLDialect.MARIADB  ).selectOne().getSQL();
DSL.using(SQLDialect.MYSQL    ).selectOne().getSQL();
DSL.using(SQLDialect.ORACLE   ).selectOne().getSQL();
DSL.using(SQLDialect.POSTGRES ).selectOne().getSQL();
DSL.using(SQLDialect.SQLITE   ).selectOne().getSQL();
DSL.using(SQLDialect.SQLSERVER).selectOne().getSQL();
DSL.using(SQLDialect.SYBASE   ).selectOne().getSQL();

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.

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 using "prefix" notation
Field<String> field2 = trim(BOOK.TITLE);

// The same function created from a pre-existing Field using "postfix" notation
Field<String> field3 = BOOK.TITLE.trim();

// More complex function with advanced DSL syntax
Field<String> field4 = listAgg(BOOK.TITLE)
                          .withinGroupOrderBy(BOOK.ID.asc())
                          .over().partitionBy(AUTHOR.ID);

In general, it is up to you whether you want to use the "prefix" notation or the "postfix" notation to create new column expressions based on existing ones. The "SQL way" would be to use the "prefix notation", with functions created from the DSL. The "Java way" or "object-oriented way" would be to use the "postfix" notation with functions created from org.jooq.Field objects. Both ways ultimately create the same query part, though.

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. 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.

See the manual's section about generated tables for more information about what is really generated by the code generator

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, val(" "), 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.

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(TAuthor.LAST_NAME.cast(PostgresDataType.TEXT)).fetch();

The same thing can be achieved by casting a Field directly to String.class, as TEXT is the default data type in Postgres to map to Java's String

create.select(TAuthor.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);
}

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.

Many databases support "collations", which defines the sort order on character data types, such as VARCHAR.

Such databases usually allow for specifying:

  • System-wide default collations
  • Session-wide default collations
  • Per-table specific default collations
  • Per-column specific default collations
  • Per-usage specific collation

The actual implementation is vendor-specific, including the way the above defaults override each other.

To accommodate most use-cases jOOQ 3.11 introduced the org.jooq.Collation type, which can be attached to a org.jooq.DataType through DataType.collate(Collation), or to a org.jooq.Field through Field.collate(Collation), for example:

SELECT * 
FROM book 
ORDER BY title COLLATE utf8_bin
create.selectFrom(BOOK)
      .orderBy(BOOK.TITLE.collate("utf8_bin"))
      .fetch();

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:

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();

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.

This is a list of general functions supported by jOOQ's DSL:

  • COALESCE: Get the first non-null value in a list of arguments.
  • NULLIF: Return NULL if both arguments are equal, or the first argument, otherwise.
  • NVL: Get the first non-null value among two arguments.
  • NVL2: Get the second argument if the first is null, or the third argument, otherwise.

Please refer to the DSL Javadoc for more details.

Math can be done efficiently in the database before returning results to your Java application. 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.

This is a list of numeric functions supported by jOOQ's DSL:

  • ABS: Get the absolute value of a value.
  • ACOS: Get the arc cosine of a value.
  • ASIN: Get the arc sine of a value.
  • ATAN: Get the arc tangent of a value.
  • ATAN2: Get the atan2 function of two values.
  • CEIL: Get the smalles integer value larger than a given numeric value.
  • COS: Get the cosine of a value.
  • COSH: Get the hyperbolic cosine of a value.
  • COT: Get the cotangent of a value.
  • COTH: Get the hyperbolic cotangent of a value.
  • DEG: Transform radians into degrees.
  • EXP: Calculate e^value.
  • FLOOR: Get the largest integer value smaller than a given numeric value.
  • GREATEST: Finds the greatest among all argument values (can also be used with non-numeric values).
  • LEAST: Finds the least among all argument values (can also be used with non-numeric values).
  • LN: Get the natural logarithm of a value.
  • LOG: Get the logarithm of a value given a base.
  • POWER: Calculate value^exponent.
  • RAD: Transform degrees into radians.
  • RAND: Get a random number.
  • ROUND: Rounds a value to the nearest integer.
  • SIGN: Get the sign of a value (-1, 0, 1).
  • SIN: Get the sine of a value.
  • SINH: Get the hyperbolic sine of a value.
  • SQRT: Calculate the square root of a value.
  • TAN: Get the tangent of a value.
  • TANH: Get the hyperbolic tangent of a value.
  • TRUNC: Truncate the decimals off a given value.

Please refer to the DSL Javadoc for more details.

Interestingly, bitwise functions and bitwise arithmetic is not very popular among SQL databases. 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, all bitwise functions are prefixed with "bit"

  • BIT_COUNT: Count the number of bits set to 1 in a number
  • BIT_AND: Set only those bits that are set in two numbers
  • BIT_OR: Set all bits that are set in at least one number
  • BIT_NAND: Set only those bits that are set in two numbers, and inverse the result
  • BIT_NOR: Set all bits that are set in at least one number, and inverse the result
  • BIT_NOT: Inverse the bits in a number
  • BIT_XOR: Set all bits that are set in at exactly one number
  • BIT_XNOR: Set all bits that are set in at exactly one number, and inverse the result
  • SHL: Shift bits to the left
  • SHR: Shift bits to the right

Some background about bitwise operation emulation

As stated before, not all databases support all of these bitwise operations. jOOQ emulates them wherever this is possible. More details can be seen in this blog post:
http://blog.jooq.org/2011/10/30/the-comprehensive-sql-bitwise-operations-compatibility-list/

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.

This is a list of numeric functions supported by jOOQ's DSL:

  • ASCII: Get the ASCII code of a character.
  • BIT_LENGTH: Get the length of a string in bits.
  • CHAR_LENGTH: Get the length of a string in characters.
  • CONCAT: Concatenate several strings.
  • ESCAPE: Escape a string for use with the LIKE predicate.
  • LENGTH: Get the length of a string.
  • LOWER: Get a string in lower case letters.
  • LPAD: Pad a string on the left side.
  • LTRIM: Trim a string on the left side.
  • OCTET_LENGTH: Get the length of a string in octets.
  • POSITION: Find a string within another string.
  • REPEAT: Repeat a string a given number of times.
  • REPLACE: Replace a string within another string.
  • RPAD: Pad a string on the right side.
  • RTRIM: Trim a string on the right side.
  • SUBSTRING: Get a substring of a string.
  • TRIM: Trim a string on both sides.
  • UPPER: Get a string in upper case letters.

Please refer to the DSL Javadoc for more details.

Regular expressions, REGEXP, REGEXP_LIKE, etc.

Various databases have some means of searching through columns using regular expressions if the LIKE predicate does not provide sufficient pattern matching power. While there are many different functions and operators in the various databases, jOOQ settled for the SQL:2008 standard REGEX_LIKE operator. Being an operator (and not a function), you should use the corresponding method on org.jooq.Field:

create.selectFrom(BOOK).where(TITLE.likeRegex("^.*SQL.*$")).fetch();

Note that the SQL standard specifies that patterns should follow the XQuery standards. In the real world, the POSIX regular expression standard is the most used one, some use Java regular expressions, and only a few ones use Perl regular expressions. jOOQ does not make any assumptions about regular expression syntax. For cross-database compatibility, please read the relevant database manuals carefully, to learn about the appropriate syntax. Please refer to the DSL Javadoc for more details.

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();

This is a list of date and time functions supported by jOOQ's DSL:

  • CURRENT_DATE: Get current date as a DATE object.
  • CURRENT_TIME: Get current time as a TIME object.
  • CURRENT_TIMESTAMP: Get current date as a TIMESTAMP object.
  • DATE_ADD: Add a number of days or an interval to a date.
  • DATE_DIFF: Get the difference in days between two dates.
  • TIMESTAMP_ADD: Add a number of days or an interval to a timestamp.
  • TIMESTAMP_DIFF: Get the difference as an INTERVAL DAY TO SECOND between two dates.

Intervals in jOOQ

jOOQ fills a gap opened by JDBC, which neglects an important SQL data type as defined by the SQL standards: INTERVAL types. See the manual's section about INTERVAL data types for more details.

This is a list of system functions supported by jOOQ's DSL:

  • CURRENT_USER: Get current user.

Aggregate functions work just like functions, even if they have a slightly different semantics. Here are some example aggregate functions from the DSL:

// Every-day, SQL standard aggregate functions
AggregateFunction<Integer>    count();
AggregateFunction<Integer>    count(Field<?> field);
AggregateFunction<T>          max  (Field<T> field);
AggregateFunction<T>          min  (Field<T> field);
AggregateFunction<BigDecimal> sum  (Field<? extends Number> field);
AggregateFunction<BigDecimal> avg  (Field<? extends Number> field);

// DISTINCT keyword in aggregate functions
AggregateFunction<Integer>    countDistinct(Field<?> field);
AggregateFunction<T>          maxDistinct  (Field<T> field);
AggregateFunction<T>          minDistinct  (Field<T> field);
AggregateFunction<BigDecimal> sumDistinct  (Field<? extends Number> field);
AggregateFunction<BigDecimal> avgDistinct  (Field<? extends Number> field);

// String aggregate functions
AggregateFunction<String> groupConcat        (Field<?> field);
AggregateFunction<String> groupConcatDistinct(Field<?> field);
OrderedAggregateFunction<String> listAgg(Field<?> field);
OrderedAggregateFunction<String> listAgg(Field<?> field, String separator);

// Statistical functions
AggregateFunction<BigDecimal> median    (Field<? extends Number> field);
AggregateFunction<BigDecimal> stddevPop (Field<? extends Number> field);
AggregateFunction<BigDecimal> stddevSamp(Field<? extends Number> field);
AggregateFunction<BigDecimal> varPop    (Field<? extends Number> field);
AggregateFunction<BigDecimal> varSamp   (Field<? extends Number> field);

// Linear regression functions
AggregateFunction<BigDecimal> regrAvgX     (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrAvgY     (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrCount    (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrIntercept(Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrR2       (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrSlope    (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrSXX      (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrSXY      (Field<? extends Number> y, Field<? extends Number> x);
AggregateFunction<BigDecimal> regrSYY      (Field<? extends Number> y, Field<? extends Number> x);

Here's an example, counting the number of books any author has written:

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

Aggregate functions have strong limitations about when they may be used and when not. For instance, you can use aggregate functions in scalar queries. Typically, this means you only select aggregate functions, no regular columns or other column expressions. Another use case is to use them along with a GROUP BY clause as seen in the previous example. Note, that jOOQ does not check whether your using of aggregate functions is correct according to the SQL standards, or according to your database's behaviour.

Filtered aggregate functions

The SQL standard specifies an optional FILTER clause, that can be appended to all aggregate functions. This is very useful to implement "pivot" tables, such as the following:

SELECT
  count(*),
  count(*) FILTER (WHERE TITLE LIKE 'A%')
FROM BOOK
create.select(
         count(),
         count().filterWhere(BOOK.TITLE.like("A%")))
      .from(BOOK)

It is usually a good idea to calculate multiple aggregate functions in a single query, if this is possible.

Only few databases (e.g. HSQLDB, PostgreSQL) implement native support for the FILTER clause. In all other databases, jOOQ emulates the clause using a CASE expression:

SELECT
  count(*),
  count(CASE WHEN TITLE LIKE 'A%' THEN 1 END)
FROM BOOK

Aggregate functions exclude NULL values from aggregation, so the above query is equivalent to the one using FILTER.

Ordered-set aggregate functions

Oracle and some other databases support "ordered-set aggregate functions". This means you can provide an ORDER BY clause to an aggregate function, which will be taken into consideration when aggregating. The best example for this is Oracle's LISTAGG() (also known as GROUP_CONCAT in other SQL dialects). The following query groups by authors and concatenates their books' titles

SELECT   LISTAGG(TITLE, ', ')
         WITHIN GROUP (ORDER BY TITLE)
FROM     BOOK
GROUP BY AUTHOR_ID
 
create.select(listAgg(BOOK.TITLE, ", ")
      .withinGroupOrderBy(BOOK.TITLE))
      .from(BOOK)
      .groupBy(BOOK.AUTHOR_ID)
      .fetch();

The above query might yield:

+---------------------+
| LISTAGG             |
+---------------------+
| 1984, Animal Farm   |
| O Alquimista, Brida |
+---------------------+

FIRST and LAST: Oracle's "ranked" aggregate functions

Oracle allows for restricting aggregate functions using the KEEP() clause, which is supported by jOOQ. In Oracle, some aggregate functions (MIN, MAX, SUM, AVG, COUNT, VARIANCE, or STDDEV) can be restricted by this clause, hence org.jooq.AggregateFunction also allows for specifying it. Here are a couple of examples using this clause:

SUM(BOOK.AMOUNT_SOLD)
  KEEP(DENSE_RANK FIRST ORDER BY BOOK.AUTHOR_ID)
sum(BOOK.AMOUNT_SOLD)
  .keepDenseRankFirstOrderBy(BOOK.AUTHOR_ID)

User-defined aggregate functions

jOOQ also supports using your own user-defined aggregate functions. See the manual's section about user-defined aggregate functions for more details.

Window functions / analytical functions

In those databases that support window functions, jOOQ's org.jooq.AggregateFunction can be transformed into a window function / analytical function by calling over() on it. See the manual's section about window functions for more details.

Most major RDBMS support the concept of window functions. jOOQ knows of implementations in DB2, Oracle, Postgres, SQL Server, and Sybase SQL Anywhere, and supports most of their specific syntaxes. Note, that H2 and HSQLDB have implemented ROW_NUMBER() functions, without true windowing support.

As previously discussed, any org.jooq.AggregateFunction can be transformed into a window function using the over() method. See the chapter about aggregate functions for details. In addition to those, there are also some more window functions supported by jOOQ, as declared in the DSL:

// Ranking functions
    WindowOverStep<Integer>    rowNumber();
    WindowOverStep<Integer>    rank();
    WindowOverStep<Integer>    denseRank();
    WindowOverStep<BigDecimal> percentRank();
    
// Windowing functions
<T> WindowIgnoreNullsStep<T>   firstValue(Field<T> field);
<T> WindowIgnoreNullsStep<T>   lastValue(Field<T> field);
<T> WindowIgnoreNullsStep<T>   nthValue(Field<T> field, int nth);
<T> WindowIgnoreNullsStep<T>   nthValue(Field<T> field, Field<Integer> nth);
<T> WindowIgnoreNullsStep<T>   lead(Field<T> field);
<T> WindowIgnoreNullsStep<T>   lead(Field<T> field, int offset);
<T> WindowIgnoreNullsStep<T>   lead(Field<T> field, int offset, T defaultValue);
<T> WindowIgnoreNullsStep<T>   lead(Field<T> field, int offset, Field<T> defaultValue);
<T> WindowIgnoreNullsStep<T>   lag(Field<T> field);
<T> WindowIgnoreNullsStep<T>   lag(Field<T> field, int offset);
<T> WindowIgnoreNullsStep<T>   lag(Field<T> field, int offset, T defaultValue);
<T> WindowIgnoreNullsStep<T>   lag(Field<T> field, int offset, Field<T> defaultValue);

// Statistical functions
    WindowOverStep<BigDecimal> cumeDist();
    WindowOverStep<Integer>    ntile(int number);
    
// Inverse distribution functions
    OrderedAggregateFunction<BigDecimal> precentileCont(Number number);
    OrderedAggregateFunction<BigDecimal> precentileCont(Field<? extends Number> number);
    OrderedAggregateFunction<BigDecimal> precentileDisc(Number number);
    OrderedAggregateFunction<BigDecimal> precentileDisc(Field<? extends Number> number);

SQL distinguishes between various window function types (e.g. "ranking functions"). Depending on the function, SQL expects mandatory PARTITION BY or ORDER BY clauses within the OVER() clause. jOOQ does not enforce those rules for two reasons:

  • Your JDBC driver or database already checks SQL syntax semantics
  • Not all databases behave correctly according to the SQL standard

If possible, however, jOOQ tries to render missing clauses for you, if a given SQL dialect is more restrictive.

Some examples

Here are some simple examples of window functions with jOOQ:

-- Sample uses of ROW_NUMBER()
ROW_NUMBER() OVER()
ROW_NUMBER() OVER(PARTITION BY 1)
ROW_NUMBER() OVER(ORDER BY BOOK.ID)
ROW_NUMBER() OVER(PARTITION BY BOOK.AUTHOR_ID ORDER BY BOOK.ID)
                  
-- Sample uses of FIRST_VALUE
FIRST_VALUE(BOOK.ID) OVER()
FIRST_VALUE(BOOK.ID IGNORE NULLS) OVER()
FIRST_VALUE(BOOK.ID RESPECT NULLS) OVER()
// Sample uses of rowNumber()
rowNumber().over()
rowNumber().over().partitionByOne()
rowNumber().over().partitionBy(BOOK.AUTHOR_ID)
rowNumber().over().partitionBy(BOOK.AUTHOR_ID).orderBy(BOOK.ID)
                  
// Sample uses of firstValue()
firstValue(BOOK.ID).over()
firstValue(BOOK.ID).ignoreNulls().over()
firstValue(BOOK.ID).respectNulls().over()

An advanced window function example

Window functions can be used for things like calculating a "running total". The following example fetches transactions and the running total for every transaction going back to the beginning of the transaction table (ordered by booked_at). Window functions are accessible from the previously seen org.jooq.AggregateFunction type using the over() method:

SELECT booked_at, amount,
   SUM(amount) OVER (PARTITION BY 1
                     ORDER BY booked_at
                     ROWS BETWEEN UNBOUNDED PRECEDING
                     AND CURRENT ROW) AS total
  FROM transactions
 
create.select(t.BOOKED_AT, t.AMOUNT,
         sum(t.AMOUNT).over().partitionByOne()
                      .orderBy(t.BOOKED_AT)
                      .rowsBetweenUnboundedPreceding()
                      .andCurrentRow().as("total")
      .from(TRANSACTIONS.as("t"))
      .fetch();

Window functions created from ordered-set aggregate functions

In the previous chapter about aggregate functions, we have seen the concept of "ordered-set aggregate functions", such as Oracle's LISTAGG(). These functions have a window function / analytical function variant, as well. For example:

SELECT   LISTAGG(TITLE, ', ')
         WITHIN GROUP (ORDER BY TITLE)
         OVER (PARTITION BY BOOK.AUTHOR_ID)
FROM     BOOK
 
create.select(listAgg(BOOK.TITLE, ", ")
      .withinGroupOrderBy(BOOK.TITLE)
      .over().partitionBy(BOOK.AUTHOR_ID))
      .from(BOOK)
      .fetch();

Window functions created from Oracle's FIRST and LAST aggregate functions

In the previous chapter about aggregate functions, we have seen the concept of "FIRST and LAST aggregate functions". These functions have a window function / analytical function variant, as well. For example:

SUM(BOOK.AMOUNT_SOLD)
  KEEP(DENSE_RANK FIRST ORDER BY BOOK.AUTHOR_ID)
  OVER(PARTITION BY 1)
sum(BOOK.AMOUNT_SOLD)
  .keepDenseRankFirstOrderBy(BOOK.AUTHOR_ID)
  .over().partitionByOne();

Window functions created from user-defined aggregate functions

User-defined aggregate functions also implement org.jooq.AggregateFunction, hence they can also be transformed into window functions using over(). This is supported by Oracle in particular. See the manual's section about user-defined aggregate functions for more details.

ROLLUP() explained in SQL

The SQL standard defines special functions that can be used in the GROUP BY clause: the grouping functions. These functions can be used to generate several groupings in a single clause. This can best be explained in SQL. Let's take ROLLUP() for instance:

-- ROLLUP() with one argument
SELECT AUTHOR_ID, COUNT(*)
FROM BOOK
GROUP BY ROLLUP(AUTHOR_ID)


-- ROLLUP() with two arguments
SELECT AUTHOR_ID, PUBLISHED_IN, COUNT(*)
FROM BOOK
GROUP BY ROLLUP(AUTHOR_ID, PUBLISHED_IN)







-- The same query using UNION ALL:
  SELECT AUTHOR_ID, COUNT(*) FROM BOOK GROUP BY (AUTHOR_ID)
UNION ALL
  SELECT NULL, COUNT(*) FROM BOOK GROUP BY ()
ORDER BY 1 NULLS LAST

-- The same query using UNION ALL:
  SELECT AUTHOR_ID, PUBLISHED_IN, COUNT(*)
  FROM BOOK GROUP BY (AUTHOR_ID, PUBLISHED_IN)
UNION ALL
  SELECT AUTHOR_ID, NULL, COUNT(*)
  FROM BOOK GROUP BY (AUTHOR_ID)
UNION ALL
  SELECT NULL, NULL, COUNT(*)
  FROM BOOK GROUP BY ()
ORDER BY 1 NULLS LAST, 2 NULLS LAST

In English, the ROLLUP() grouping function provides N+1 groupings, when N is the number of arguments to the ROLLUP() function. Each grouping has an additional group field from the ROLLUP() argument field list. The results of the second query might look something like this:

+-----------+--------------+----------+
| AUTHOR_ID | PUBLISHED_IN | COUNT(*) |
+-----------+--------------+----------+
|         1 |         1945 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         1 |         1948 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         1 |         NULL |        2 | <- GROUP BY (AUTHOR_ID)
|         2 |         1988 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         2 |         1990 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         2 |         NULL |        2 | <- GROUP BY (AUTHOR_ID)
|      NULL |         NULL |        4 | <- GROUP BY ()
+-----------+--------------+----------+

CUBE() explained in SQL

CUBE() is different from ROLLUP() in the way that it doesn't just create N+1 groupings, it creates all 2^N possible combinations between all group fields in the CUBE() function argument list. Let's re-consider our second query from before:

-- CUBE() with two arguments
SELECT AUTHOR_ID, PUBLISHED_IN, COUNT(*)
FROM BOOK
GROUP BY CUBE(AUTHOR_ID, PUBLISHED_IN)










-- The same query using UNION ALL:
  SELECT AUTHOR_ID, PUBLISHED_IN, COUNT(*)
  FROM BOOK GROUP BY (AUTHOR_ID, PUBLISHED_IN)
UNION ALL
  SELECT AUTHOR_ID, NULL, COUNT(*)
  FROM BOOK GROUP BY (AUTHOR_ID)
UNION ALL
  SELECT NULL, PUBLISHED_IN, COUNT(*)
  FROM BOOK GROUP BY (PUBLISHED_IN)
UNION ALL
  SELECT NULL, NULL, COUNT(*)
  FROM BOOK GROUP BY ()
ORDER BY 1 NULLS FIRST, 2 NULLS FIRST

The results would then hold:

+-----------+--------------+----------+
| AUTHOR_ID | PUBLISHED_IN | COUNT(*) |
+-----------+--------------+----------+
|      NULL |         NULL |        2 | <- GROUP BY ()
|      NULL |         1945 |        1 | <- GROUP BY (PUBLISHED_IN)
|      NULL |         1948 |        1 | <- GROUP BY (PUBLISHED_IN)
|      NULL |         1988 |        1 | <- GROUP BY (PUBLISHED_IN)
|      NULL |         1990 |        1 | <- GROUP BY (PUBLISHED_IN)
|         1 |         NULL |        2 | <- GROUP BY (AUTHOR_ID)
|         1 |         1945 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         1 |         1948 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         2 |         NULL |        2 | <- GROUP BY (AUTHOR_ID)
|         2 |         1988 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
|         2 |         1990 |        1 | <- GROUP BY (AUTHOR_ID, PUBLISHED_IN)
+-----------+--------------+----------+

GROUPING SETS()

GROUPING SETS() are the generalised way to create multiple groupings. From our previous examples

  • ROLLUP(AUTHOR_ID, PUBLISHED_IN) corresponds to GROUPING SETS((AUTHOR_ID, PUBLISHED_IN), (AUTHOR_ID), ())
  • CUBE(AUTHOR_ID, PUBLISHED_IN) corresponds to GROUPING SETS((AUTHOR_ID, PUBLISHED_IN), (AUTHOR_ID), (PUBLISHED_IN), ())

This is nicely explained in the SQL Server manual pages about GROUPING SETS() and other grouping functions:
http://msdn.microsoft.com/en-us/library/bb510427(v=sql.105)

jOOQ's support for ROLLUP(), CUBE(), GROUPING SETS()

jOOQ fully supports all of these functions, as well as the utility functions GROUPING() and GROUPING_ID(), used for identifying the grouping set ID of a record. The DSL API thus includes:

// The various grouping function constructors
GroupField rollup(Field<?>... fields);
GroupField cube(Field<?>... fields);
GroupField groupingSets(Field<?>... fields);
GroupField groupingSets(Field<?>[]... fields);
GroupField groupingSets(Collection<? extends Field<?>>... fields);

// The utility functions generating IDs per GROUPING SET
Field<Integer> grouping(Field<?>);
Field<Integer> groupingId(Field<?>...);

MySQL's and CUBRID's WITH ROLLUP syntax

MySQL and CUBRID don't know any grouping functions, but they support a WITH ROLLUP clause, that is equivalent to simple ROLLUP() grouping functions. jOOQ emulates ROLLUP() in MySQL and CUBRID, by rendering this WITH ROLLUP clause. The following two statements mean the same:

-- Statement 1: SQL standard
GROUP BY ROLLUP(A, B, C)

-- Statement 2: SQL standard
GROUP BY A, ROLLUP(B, C)
-- Statement 1: MySQL
GROUP BY A, B, C WITH ROLLUP

-- Statement 2: MySQL
-- This is not supported in MySQL

Some databases support user-defined functions, which can be embedded in any SQL statement, if you're using jOOQ's code generator. Let's say you have the following simple function in Oracle SQL:

CREATE OR REPLACE FUNCTION echo (INPUT NUMBER)
RETURN NUMBER
IS
BEGIN
    RETURN INPUT;
END echo;

The above function will be made available from a generated Routines class. You can use it like any other column expression:

SELECT echo(1) FROM DUAL WHERE echo(2) = 2
create.select(echo(1)).where(echo(2).eq(2)).fetch();

Note that user-defined functions returning CURSOR or ARRAY data types can also be used wherever table expressions can be used, if they are unnested

Some databases support user-defined aggregate functions, which can then be used along with GROUP BY clauses or as window functions. An example for such a database is Oracle. With Oracle, you can define the following OBJECT type (the example was taken from the Oracle 11g documentation):

CREATE TYPE U_SECOND_MAX AS OBJECT
(
  MAX NUMBER, -- highest value seen so far
  SECMAX NUMBER, -- second highest value seen so far
  STATIC FUNCTION ODCIAggregateInitialize(sctx IN OUT U_SECOND_MAX) RETURN NUMBER,
  MEMBER FUNCTION ODCIAggregateIterate(self IN OUT U_SECOND_MAX, value IN NUMBER) RETURN NUMBER,
  MEMBER FUNCTION ODCIAggregateTerminate(self IN U_SECOND_MAX, returnValue OUT NUMBER, flags IN NUMBER) RETURN NUMBER,
  MEMBER FUNCTION ODCIAggregateMerge(self IN OUT U_SECOND_MAX, ctx2 IN U_SECOND_MAX) RETURN NUMBER
);

CREATE OR REPLACE TYPE BODY U_SECOND_MAX IS
STATIC FUNCTION ODCIAggregateInitialize(sctx IN OUT U_SECOND_MAX)
RETURN NUMBER IS
BEGIN
  SCTX := U_SECOND_MAX(0, 0);
  RETURN ODCIConst.Success;
END;

MEMBER FUNCTION ODCIAggregateIterate(self IN OUT U_SECOND_MAX, value IN NUMBER) RETURN NUMBER IS
BEGIN
  IF VALUE > SELF.MAX THEN
    SELF.SECMAX := SELF.MAX;
    SELF.MAX := VALUE;
  ELSIF VALUE > SELF.SECMAX THEN
    SELF.SECMAX := VALUE;
  END IF;
  RETURN ODCIConst.Success;
END;

MEMBER FUNCTION ODCIAggregateTerminate(self IN U_SECOND_MAX, returnValue OUT NUMBER, flags IN NUMBER) RETURN NUMBER IS
BEGIN
  RETURNVALUE := SELF.SECMAX;
  RETURN ODCIConst.Success;
END;

MEMBER FUNCTION ODCIAggregateMerge(self IN OUT U_SECOND_MAX, ctx2 IN U_SECOND_MAX) RETURN NUMBER IS
BEGIN
  IF CTX2.MAX > SELF.MAX THEN
    IF CTX2.SECMAX > SELF.SECMAX THEN
      SELF.SECMAX := CTX2.SECMAX;
    ELSE
      SELF.SECMAX := SELF.MAX;
    END IF;
    SELF.MAX := CTX2.MAX;
  ELSIF CTX2.MAX > SELF.SECMAX THEN
    SELF.SECMAX := CTX2.MAX;
  END IF;
  RETURN ODCIConst.Success;
END;
END;

The above OBJECT type is then available to function declarations as such:

CREATE FUNCTION SECOND_MAX (input NUMBER) RETURN NUMBER
PARALLEL_ENABLE AGGREGATE USING U_SECOND_MAX;

Using the generated aggregate function

jOOQ's code generator will detect such aggregate functions and generate them differently from regular user-defined functions. They implement the org.jooq.AggregateFunction type, as mentioned in the manual's section about aggregate functions. Here's how you can use the SECOND_MAX() aggregate function with jOOQ:

-- Get the second-latest publishing date by author
SELECT SECOND_MAX(PUBLISHED_IN)
FROM BOOK
GROUP BY AUTHOR_ID
 
// Routines.secondMax() can be static-imported
create.select(secondMax(BOOK.PUBLISHED_IN))
      .from(BOOK)
      .groupBy(BOOK.AUTHOR_ID)
      .fetch();

The CASE expression is part of the standard SQL syntax. While some RDBMS also offer an IF expression, or a DECODE function, you can always rely on the two types of CASE syntax:

CASE WHEN AUTHOR.FIRST_NAME = 'Paulo'  THEN 'brazilian'
     WHEN AUTHOR.FIRST_NAME = 'George' THEN 'english'
                                       ELSE 'unknown'
END

-- OR:

CASE AUTHOR.FIRST_NAME WHEN 'Paulo'  THEN 'brazilian'
                       WHEN 'George' THEN 'english'
                                     ELSE 'unknown'
END
DSL
      .when(AUTHOR.FIRST_NAME.eq("Paulo"), "brazilian")
      .when(AUTHOR.FIRST_NAME.eq("George"), "english")
      .otherwise("unknown");

// OR:

DSL.choose(AUTHOR.FIRST_NAME)
   .when("Paulo", "brazilian")
   .when("George", "english")
   .otherwise("unknown");

In jOOQ, both syntaxes are supported (The second one is emulated in Derby, which only knows the first one). Unfortunately, both case and else are reserved words in Java. jOOQ chose to use decode() from the Oracle DECODE function, or choose(), and otherwise(), which means the same as else.

A CASE expression can be used anywhere where you can place a column expression (or Field). For instance, you can SELECT the above expression, if you're selecting from AUTHOR:

SELECT AUTHOR.FIRST_NAME, [... CASE EXPR ...] AS nationality
  FROM AUTHOR

The Oracle DECODE() function

Oracle knows a more succinct, but maybe less readable DECODE() function with a variable number of arguments. This function roughly does the same as the second case expression syntax. jOOQ supports the DECODE() function and emulates it using CASE expressions in all dialects other than Oracle:

-- Oracle:
DECODE(FIRST_NAME, 'Paulo', 'brazilian',
                   'George', 'english',
                   'unknown');

-- Other SQL dialects
CASE AUTHOR.FIRST_NAME WHEN 'Paulo'  THEN 'brazilian'
                       WHEN 'George' THEN 'english'
                                     ELSE 'unknown'
END




// Use the Oracle-style DECODE() function with jOOQ.
// Note, that you will not be able to rely on type-safety
DSL.decode(AUTHOR.FIRST_NAME,
    "Paulo", "brazilian",
    "George", "english",
    "unknown");

CASE clauses in an ORDER BY clause

Sort indirection is often implemented with a CASE clause of a SELECT's ORDER BY clause. See the manual's section about the ORDER BY clause for more details.

Sequences implement the org.jooq.Sequence interface, providing essentially this functionality:

// Get a field for the CURRVAL sequence property
Field<T> currval();

// Get a field for the NEXTVAL sequence property
Field<T> nextval();

So if you have a sequence like this in Oracle:

CREATE SEQUENCE s_author_id

You can then use your generated sequence object directly in a SQL statement as such:

// Reference the sequence in a SELECT statement:
Field<BigInteger> s = S_AUTHOR_ID.nextval();
BigInteger nextID = create.select(s).fetchOne(s);

// Reference the sequence in an INSERT statement:
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .values(S_AUTHOR_ID.nextval(), val("William"), val("Shakespeare"))
      .execute();
  • For more information about generated sequences, refer to the manual's section about generated sequences
  • For more information about executing standalone calls to sequences, refer to the manual's section about sequence execution

According to the SQL standard, row value expressions can have a degree of more than one. This is commonly used in the INSERT statement, where the VALUES row value constructor allows for providing a row value expression as a source for INSERT data. Row value expressions can appear in various other places, though. They are supported by jOOQ as records / rows. jOOQ's DSL allows for the construction of type-safe records up to the degree of 22. Higher-degree Rows are supported as well, but without any type-safety. Row types are modelled as follows:

// The DSL provides overloaded row value expression constructor methods:
public static <T1>             Row1<T1>             row(T1 t1)                      { ... }
public static <T1, T2>         Row2<T1, T2>         row(T1 t1, T2 t2)               { ... }
public static <T1, T2, T3>     Row3<T1, T2, T3>     row(T1 t1, T2 t2, T3 t3)        { ... }
public static <T1, T2, T3, T4> Row4<T1, T2, T3, T4> row(T1 t1, T2 t2, T3 t3, T4 t4) { ... }

// [ ... idem for Row5, Row6, Row7, ..., Row22 ]

// Degrees of more than 22 are supported without type-safety
public static RowN row(Object... values) { ... }

Using row value expressions in predicates

Row value expressions are incompatible with most other QueryParts, but they can be used as a basis for constructing various conditional expressions, such as:

See the relevant sections for more details about how to use row value expressions in predicates.

Using row value expressions in UPDATE statements

The UPDATE statement also supports a variant where row value expressions are updated, rather than single columns. See the relevant section for more details

Higher-degree row value expressions

jOOQ chose to explicitly support degrees up to 22 to match Scala's typesafe tuple, function and product support. Unlike Scala, however, jOOQ also supports higher degrees without the additional typesafety.

Conditions or conditional expressions are widely used in SQL and in the jOOQ API. They can be used in

Boolean types in SQL

Before SQL:1999, boolean types did not really exist in SQL. They were modelled by 0 and 1 numeric/char values. With SQL:1999, true booleans were introduced and are now supported by most databases. In short, these are possible boolean values:

  • 1 or TRUE
  • 0 or FALSE
  • NULL or UNKNOWN

It is important to know that SQL differs from many other languages in the way it interprets the NULL boolean value. Most importantly, the following facts are to be remembered:

  • [ANY] = NULL yields NULL (not FALSE)
  • [ANY] != NULL yields NULL (not TRUE)
  • NULL = NULL yields NULL (not TRUE)
  • NULL != NULL yields NULL (not FALSE)

For simplified NULL handling, please refer to the section about the DISTINCT predicate.

Note that jOOQ does not model these values as actual column expression compatible.

With jOOQ, most conditional expressions are built from column expressions, calling various methods on them. For instance, to build a comparison predicate, you can write the following expression:

TITLE  = 'Animal Farm'
TITLE != 'Animal Farm'
BOOK.TITLE.eq("Animal Farm")
BOOK.TITLE.ne("Animal Farm")

Create conditions from the DSL

There are a few types of conditions, that can be created statically from the DSL. These are:

Connect conditions using boolean operators

Conditions can also be connected using boolean operators as will be discussed in a subsequent chapter.

In SQL, as in most other languages, conditional expressions can be connected using the AND and OR binary operators, as well as the NOT unary operator, to form new conditional expressions. In jOOQ, this is modelled as such:

-- A simple conditional expression
TITLE = 'Animal Farm' OR TITLE = '1984'

-- A more complex conditional expression
        (TITLE = 'Animal Farm' OR TITLE = '1984')
AND NOT (AUTHOR.LAST_NAME = 'Orwell')
// A simple boolean connection
BOOK.TITLE.eq("Animal Farm").or(BOOK.TITLE.eq("1984"))

// A more complex conditional expression
BOOK.TITLE.eq("Animal Farm").or(BOOK.TITLE.eq("1984"))
    .andNot(AUTHOR.LAST_NAME.eq("Orwell"))

The above example shows that the number of parentheses in Java can quickly explode. Proper indentation may become crucial in making such code readable. In order to understand how jOOQ composes combined conditional expressions, let's assign component expressions first:

Condition a = BOOK.TITLE.eq("Animal Farm");
Condition b = BOOK.TITLE.eq("1984");
Condition c = AUTHOR.LAST_NAME.eq("Orwell");

Condition combined1 = a.or(b);             // These OR-connected conditions form a new condition, wrapped in parentheses
Condition combined2 = combined1.andNot(c); // The left-hand side of the AND NOT () operator is already wrapped in parentheses

The Condition API

Here are all boolean operators on the org.jooq.Condition interface:

and(Condition)            // Combine conditions with AND
and(String)               // Combine conditions with AND. Convenience for adding plain SQL to the right-hand side
and(String, Object...)    // Combine conditions with AND. Convenience for adding plain SQL to the right-hand side
and(String, QueryPart...) // Combine conditions with AND. Convenience for adding plain SQL to the right-hand side
andExists(Select<?>)      // Combine conditions with AND. Convenience for adding an exists predicate to the rhs
andNot(Condition)         // Combine conditions with AND. Convenience for adding an inverted condition to the rhs
andNotExists(Select<?>)   // Combine conditions with AND. Convenience for adding an inverted exists predicate to the rhs

or(Condition)             // Combine conditions with OR
or(String)                // Combine conditions with OR. Convenience for adding plain SQL to the right-hand side
or(String, Object...)     // Combine conditions with OR. Convenience for adding plain SQL to the right-hand side
or(String, QueryPart...)  // Combine conditions with OR. Convenience for adding plain SQL to the right-hand side
orExists(Select<?>)       // Combine conditions with OR. Convenience for adding an exists predicate to the rhs
orNot(Condition)          // Combine conditions with OR. Convenience for adding an inverted condition to the rhs
orNotExists(Select<?>)    // Combine conditions with OR. Convenience for adding an inverted exists predicate to the rhs

not()                     // Invert a condition (synonym for DSL.not(Condition)

In SQL, comparison predicates are formed using common comparison operators:

  • = to test for equality
  • <> or != to test for non-equality
  • > to test for being strictly greater
  • >= to test for being greater or equal
  • < to test for being strictly less
  • <= to test for being less or equal

Unfortunately, Java does not support operator overloading, hence these operators are also implemented as methods in jOOQ, like any other SQL syntax elements. The relevant parts of the org.jooq.Field interface are these:

eq or equal(T);                                     // =  (some bind value)
eq or equal(Field<T>);                              // =  (some column expression)
eq or equal(Select<? extends Record1<T>>);          // =  (some scalar SELECT statement)
ne or notEqual(T);                                  // <> (some bind value)
ne or notEqual(Field<T>);                           // <> (some column expression)
ne or notEqual(Select<? extends Record1<T>>);       // <> (some scalar SELECT statement)
lt or lessThan(T);                                  // <  (some bind value)
lt or lessThan(Field<T>);                           // <  (some column expression)
lt or lessThan(Select<? extends Record1<T>>);       // <  (some scalar SELECT statement)
le or lessOrEqual(T);                               // <= (some bind value)
le or lessOrEqual(Field<T>);                        // <= (some column expression)
le or lessOrEqual(Select<? extends Record1<T>>);    // <= (some scalar SELECT statement)
gt or greaterThan(T);                               // >  (some bind value)
gt or greaterThan(Field<T>);                        // >  (some column expression)
gt or greaterThan(Select<? extends Record1<T>>);    // >  (some scalar SELECT statement)
ge or greaterOrEqual(T);                            // >= (some bind value)
ge or greaterOrEqual(Field<T>);                     // >= (some column expression)
ge or greaterOrEqual(Select<? extends Record1<T>>); // >= (some scalar SELECT statement)

Note that every operator is represented by two methods. A verbose one (such as equal()) and a two-character one (such as eq()). Both methods are the same. You may choose either one, depending on your taste. The manual will always use the more verbose one.

jOOQ's convenience methods using comparison operators

In addition to the above, jOOQ provides a few convenience methods for common operations performed on strings using comparison predicates:

-- case insensitivity
LOWER(TITLE)  = LOWER('animal farm')
LOWER(TITLE) <> LOWER('animal farm')
// case insensitivity
BOOK.TITLE.equalIgnoreCase("animal farm")
BOOK.TITLE.notEqualIgnoreCase("animal farm")

As previously mentioned in the manual's section about arithmetic expressions, jOOQ does not implement operator precedence. All operators are evaluated from left to right, as expected in an object-oriented API. This is important to understand when combining boolean operators, such as AND, OR, and NOT. The following expressions are equivalent:

   A.and(B) .or(C) .and(D) .or(E)
(((A.and(B)).or(C)).and(D)).or(E)

In SQL, the two expressions wouldn't be the same, as SQL natively knows operator precedence.

   A AND B  OR C  AND D  OR E -- Precedence is applied
(((A AND B) OR C) AND D) OR E -- Precedence is overridden

All variants of the comparison predicate that we've seen in the previous chapter also work for row value expressions. If your database does not support row value expression comparison predicates, jOOQ emulates them the way they are defined in the SQL standard:

-- Row value expressions (equal)
(A, B)    =  (X, Y)
(A, B, C) =  (X, Y, Z)
-- greater than
(A, B)    >  (X, Y)

(A, B, C) >  (X, Y, Z)


-- greater or equal
(A, B)    >= (X, Y)


(A, B, C) >= (X, Y, Z)



-- Inverse comparisons

(A, B)    <> (X, Y)
(A, B)    <  (X, Y)
(A, B)    <= (X, Y)
-- Equivalent factored-out predicates (equal)
(A = X) AND (B = Y)
(A = X) AND (B = Y) AND (C = Z)
-- greater than
(A > X)
  OR ((A = X) AND (B > Y))
(A > X)
  OR ((A = X) AND (B > Y))
  OR ((A = X) AND (B = Y) AND (C > Z))
-- greater or equal
(A > X)
  OR ((A = X) AND (B > Y))
  OR ((A = X) AND (B = Y))
(A > X)
  OR ((A = X) AND (B > Y))
  OR ((A = X) AND (B = Y) AND (C > Z))
  OR ((A = X) AND (B = Y) AND (C = Z))
-- For simplicity, these predicates are shown in terms
-- of their negated counter parts
NOT((A, B) =  (X, Y))
NOT((A, B) >= (X, Y))
NOT((A, B) >  (X, Y))

jOOQ supports all of the above row value expression comparison predicates, both with column expression lists and scalar subselects at the right-hand side:

-- With regular column expressions
(BOOK.AUTHOR_ID, BOOK.TITLE) = (1, 'Animal Farm')

-- With scalar subselects
(BOOK.AUTHOR_ID, BOOK.TITLE) = (
  SELECT PERSON.ID, 'Animal Farm'
  FROM PERSON
  WHERE PERSON.ID = 1
)
// Column expressions
row(BOOK.AUTHOR_ID, BOOK.TITLE).eq(1, "Animal Farm");

// Subselects
row(BOOK.AUTHOR_ID, BOOK.TITLE).eq(
  select(PERSON.ID, val("Animal Farm"))
  .from(PERSON)
  .where(PERSON.ID.eq(1))
);

If the right-hand side of a comparison predicate turns out to be a non-scalar table subquery, you can wrap that subquery in a quantifier, such as ALL, ANY, or SOME. Note that the SQL standard defines ANY and SOME to be equivalent. jOOQ settled for the more intuitive ANY and doesn't support SOME. Here are some examples, supported by jOOQ:

TITLE = ANY('Animal Farm', '1982')
PUBLISHED_IN > ALL(1920, 1940)
BOOK.TITLE.eq(any("Animal Farm", "1982"));
BOOK.PUBLISHED_IN.gt(all(1920, 1940));

For the example, the right-hand side of the quantified comparison predicates were filled with argument lists. But it is easy to imagine that the source of values results from a subselect.

ANY and the IN predicate

It is interesting to note that the SQL standard defines the IN predicate in terms of the ANY-quantified predicate. The following two expressions are equivalent:

[ROW VALUE EXPRESSION] IN [IN PREDICATE VALUE]
[ROW VALUE EXPRESSION] = ANY [IN PREDICATE VALUE]

Typically, the IN predicate is more readable than the quantified comparison predicate.

In SQL, you cannot compare NULL with any value using comparison predicates, as the result would yield NULL again, which is neither TRUE nor FALSE (see also the manual's section about conditional expressions). In order to test a column expression for NULL, use the NULL predicate as such:

TITLE IS NULL
TITLE IS NOT NULL
BOOK.TITLE.isNull()
BOOK.TITLE.isNotNull()

The SQL NULL predicate also works well for row value expressions, although it has some subtle, counter-intuitive features when it comes to inversing predicates with the NOT() operator! Here are some examples:

-- Row value expressions
(A, B) IS     NULL
(A, B) IS NOT NULL

-- Inverse of the above
NOT((A, B) IS     NULL)
NOT((A, B) IS NOT NULL)
-- Equivalent factored-out predicates
(A IS     NULL) AND (B IS     NULL)
(A IS NOT NULL) AND (B IS NOT NULL)

-- Inverse
(A IS NOT NULL) OR  (B IS NOT NULL)
(A IS     NULL) OR  (B IS     NULL)

The SQL standard contains a nice truth table for the above rules:

+-----------------------+-----------+---------------+---------------+-------------------+
| Expression            | R IS NULL | R IS NOT NULL | NOT R IS NULL | NOT R IS NOT NULL |
+-----------------------+-----------+---------------+---------------+-------------------+
| degree 1: null        | true      | false         | false         |  true             |
| degree 1: not null    | false     | true          | true          |  false            |
| degree > 1: all null  | true      | false         | false         |  true             |
| degree > 1: some null | false     | false         | true          |  true             |
| degree > 1: none null | false     | true          | true          |  false            |
+-----------------------+-----------+---------------+---------------+-------------------+

In jOOQ, you would simply use the isNull() and isNotNull() methods on row value expressions. Again, as with the row value expression comparison predicate, the row value expression NULL predicate is emulated by jOOQ, if your database does not natively support it:

row(BOOK.ID, BOOK.TITLE).isNull();
row(BOOK.ID, BOOK.TITLE).isNotNull();

Some databases support the DISTINCT predicate, which serves as a convenient, NULL-safe comparison predicate. With the DISTINCT predicate, the following truth table can be assumed:

  • [ANY] IS DISTINCT FROM NULL yields TRUE
  • [ANY] IS NOT DISTINCT FROM NULL yields FALSE
  • NULL IS DISTINCT FROM NULL yields FALSE
  • NULL IS NOT DISTINCT FROM NULL yields TRUE

For instance, you can compare two fields for distinctness, ignoring the fact that any of the two could be NULL, which would lead to funny results. This is supported by jOOQ as such:

TITLE IS DISTINCT FROM SUB_TITLE
TITLE IS NOT DISTINCT FROM SUB_TITLE
BOOK.TITLE.isDistinctFrom(BOOK.SUB_TITLE)
BOOK.TITLE.isNotDistinctFrom(BOOK.SUB_TITLE)

If your database does not natively support the DISTINCT predicate, jOOQ emulates it with an equivalent CASE expression, modelling the above truth table:

-- [A] IS DISTINCT FROM [B]
CASE WHEN [A] IS     NULL AND [B] IS     NULL THEN FALSE
     WHEN [A] IS     NULL AND [B] IS NOT NULL THEN TRUE
     WHEN [A] IS NOT NULL AND [B] IS     NULL THEN TRUE
     WHEN [A] =               [B]             THEN FALSE
     ELSE                                          TRUE
END
-- [A] IS NOT DISTINCT FROM [B]
CASE WHEN [A] IS     NULL AND [B] IS     NULL THEN TRUE
     WHEN [A] IS     NULL AND [B] IS NOT NULL THEN FALSE
     WHEN [A] IS NOT NULL AND [B] IS     NULL THEN FALSE
     WHEN [A] =               [B]             THEN TRUE
     ELSE                                          FALSE
END

... or better, if the INTERSECT set operation is supported:

-- [A] IS DISTINCT FROM [B]
NOT EXISTS(SELECT A INTERSECT SELECT B)
-- [A] IS NOT DISTINCT FROM [B]
EXISTS(SELECT a INTERSECT SELECT b)

The BETWEEN predicate can be seen as syntactic sugar for a pair of comparison predicates. According to the SQL standard, the following two predicates are equivalent:

[A] BETWEEN [B] AND [C]
[A] >= [B] AND [A] <= [C]

Note the inclusiveness of range boundaries in the definition of the BETWEEN predicate. Intuitively, this is supported in jOOQ as such:

PUBLISHED_IN     BETWEEN 1920 AND 1940
PUBLISHED_IN NOT BETWEEN 1920 AND 1940
BOOK.PUBLISHED_IN.between(1920).and(1940)
BOOK.PUBLISHED_IN.notBetween(1920).and(1940)

BETWEEN SYMMETRIC

The SQL standard defines the SYMMETRIC keyword to be used along with BETWEEN to indicate that you do not care which bound of the range is larger than the other. A database system should simply swap range bounds, in case the first bound is greater than the second one. jOOQ supports this keyword as well, emulating it if necessary.

PUBLISHED_IN     BETWEEN SYMMETRIC 1940 AND 1920
PUBLISHED_IN NOT BETWEEN SYMMETRIC 1940 AND 1920
BOOK.PUBLISHED_IN.betweenSymmetric(1940).and(1920)
BOOK.PUBLISHED_IN.notBetweenSymmetric(1940).and(1920)

The emulation is done trivially:

[A] BETWEEN SYMMETRIC [B] AND [C]
([A] BETWEEN [B] AND [C]) OR ([A] BETWEEN [C] AND [B])

The SQL BETWEEN predicate also works well for row value expressions. Much like the BETWEEN predicate for degree 1, it is defined in terms of a pair of regular comparison predicates:

[A] BETWEEN           [B] AND [C]
[A] BETWEEN SYMMETRIC [B] AND [C]
 [A] >= [B] AND [A] <= [C]
([A] >= [B] AND [A] <= [C]) OR ([A] >= [C] AND [A] <= [B])

The above can be factored out according to the rules listed in the manual's section about row value expression comparison predicates.

jOOQ supports the BETWEEN [SYMMETRIC] predicate and emulates it in all SQL dialects where necessary. An example is given here:

row(BOOK.ID, BOOK.TITLE).between(1, "A").and(10, "Z");

LIKE predicates are popular for simple wildcard-enabled pattern matching. Supported wildcards in all SQL databases are:

  • _: (single-character wildcard)
  • %: (multi-character wildcard)

With jOOQ, the LIKE predicate can be created from any column expression as such:

TITLE     LIKE '%abc%'
TITLE NOT LIKE '%abc%'
BOOK.TITLE.like("%abc%")
BOOK.TITLE.notLike("%abc%")

Escaping operands with the LIKE predicate

Often, your pattern may contain any of the wildcard characters "_" and "%", in case of which you may want to escape them. jOOQ does not automatically escape patterns in like() and notLike() methods. Instead, you can explicitly define an escape character as such:

TITLE     LIKE '%The !%-Sign Book%' ESCAPE '!'
TITLE NOT LIKE '%The !%-Sign Book%' ESCAPE '!'
BOOK.TITLE.like("%The !%-Sign Book%", '!')
BOOK.TITLE.notLike("%The !%-Sign Book%", '!')

In the above predicate expressions, the exclamation mark character is passed as the escape character to escape wildcard characters "!_" and "!%", as well as to escape the escape character itself: "!!"

Please refer to your database manual for more details about escaping patterns with the LIKE predicate.

jOOQ's convenience methods using the LIKE predicate

In addition to the above, jOOQ provides a few convenience methods for common operations performed on strings using the LIKE predicate. Typical operations are "contains predicates", "starts with predicates", "ends with predicates", etc. Here is the full convenience API wrapping LIKE predicates:

-- case insensitivity
LOWER(TITLE) LIKE LOWER('%abc%')
LOWER(TITLE) NOT LIKE LOWER('%abc%')

-- contains and similar methods
TITLE LIKE '%' || 'abc' || '%'
TITLE LIKE 'abc' || '%'
TITLE LIKE '%' || 'abc'
// case insensitivity
BOOK.TITLE.likeIgnoreCase("%abc%")
BOOK.TITLE.notLikeIgnoreCase("%abc%")

// contains and similar methods
BOOK.TITLE.contains("abc")
BOOK.TITLE.startsWith("abc")
BOOK.TITLE.endsWith("abc")

Note, that jOOQ escapes % and _ characters in value in some of the above predicate implementations. For simplicity, this has been omitted in this manual.

In SQL, apart from comparing a value against several values, the IN predicate can be used to create semi-joins or anti-joins. jOOQ knows the following methods on the org.jooq.Field interface, to construct such IN predicates:

in(Collection<T>)                   // Construct an IN predicate from a collection of bind values
in(T...)                            // Construct an IN predicate from bind values
in(Field<?>...)                     // Construct an IN predicate from column expressions
in(Select<? extends Record1<T>>)    // Construct an IN predicate from a subselect
notIn(Collection<T>)                // Construct a NOT IN predicate from a collection of bind values
notIn(T...)                         // Construct a NOT IN predicate from bind values
notIn(Field<?>...)                  // Construct a NOT IN predicate from column expressions
notIn(Select<? extends Record1<T>>) // Construct a NOT IN predicate from a subselect

A sample IN predicate might look like this:

TITLE     IN ('Animal Farm', '1984')
TITLE NOT IN ('Animal Farm', '1984')
BOOK.TITLE.in("Animal Farm", "1984")
BOOK.TITLE.notIn("Animal Farm", "1984")

NOT IN and NULL values

Beware that you should probably not have any NULL values in the right hand side of a NOT IN predicate, as the whole expression would evaluate to NULL, which is rarely desired. This can be shown informally using the following reasoning:

-- The following conditional expressions are formally or informally equivalent
A NOT IN (B, C)
A != ANY(B, C)
A != B AND A != C

-- Substitute C for NULL, you'll get
A NOT IN (B, NULL)   -- Substitute C for NULL
A != B AND A != NULL -- From the above rules
A != B AND NULL      -- [ANY] != NULL yields NULL
NULL                 -- [ANY] AND NULL yields NULL

A good way to prevent this from happening is to use the EXISTS predicate for anti-joins, which is NULL-value insensitive. See the manual's section about conditional expressions to see a boolean truth table.

The SQL IN predicate also works well for row value expressions. Much like the IN predicate for degree 1, it is defined in terms of a quantified comparison predicate. The two expressions are equivalent:

R IN [IN predicate value]
R = ANY [IN predicate value]

jOOQ supports the IN predicate with row value expressions.An example is given here:

-- Using an IN list
(BOOK.ID, BOOK.TITLE) IN ((1, 'A'), (2, 'B'))

-- Using a subselect
(BOOK.ID, BOOK.TITLE) IN (
  SELECT T.ID, T.TITLE
  FROM T 
)
// Using an IN list
row(BOOK.ID, BOOK.TITLE).in(row(1, "A"), row(2, "B"));

// Using a subselect
row(BOOK.ID, BOOK.TITLE).in(
  select(T.ID, T.TITLE)
  .from(T)
);

In both cases, i.e. when using an IN list or when using a subselect, the type of the predicate is checked. Both sides of the predicate must be of equal degree and row type.

Emulation of the IN predicate where row value expressions aren't well supported is currently only available for IN predicates that do not take a subselect as an IN predicate value.

Slightly less intuitive, yet more powerful than the previously discussed IN predicate is the EXISTS predicate, that can be used to form semi-joins or anti-joins. With jOOQ, the EXISTS predicate can be formed in various ways:

An example of an EXISTS predicate can be seen here:

    EXISTS (SELECT 1 FROM BOOK
            WHERE AUTHOR_ID = 3)
NOT EXISTS (SELECT 1 FROM BOOK
            WHERE AUTHOR_ID = 3)
   exists(create.selectOne().from(BOOK)
                .where(BOOK.AUTHOR_ID.eq(3)));
notExists(create.selectOne().from(BOOK)
                .where(BOOK.AUTHOR_ID.eq(3)));

Note that in SQL, the projection of a subselect in an EXISTS predicate is irrelevant. To help you write queries like the above, you can use jOOQ's selectZero() or selectOne() DSL methods

Performance of IN vs. EXISTS

In theory, the two types of predicates can perform equally well. If your database system ships with a sophisticated cost-based optimiser, it will be able to transform one predicate into the other, if you have all necessary constraints set (e.g. referential constraints, not null constraints). However, in reality, performance between the two might differ substantially. An interesting blog post investigating this topic on the MySQL database can be seen here:
http://blog.jooq.org/2012/07/27/not-in-vs-not-exists-vs-left-join-is-null-mysql/

When comparing dates, the SQL standard allows for using a special OVERLAPS predicate, which checks whether two date ranges overlap each other. The following can be said:

-- This yields true
(DATE '2010-01-01', DATE '2010-01-03') OVERLAPS (DATE '2010-01-02' DATE '2010-01-04')

-- INTERVAL data types are also supported. This is equivalent to the above
(DATE '2010-01-01', CAST('+2 00:00:00' AS INTERVAL DAY TO SECOND)) OVERLAPS
(DATE '2010-01-02', CAST('+2 00:00:00' AS INTERVAL DAY TO SECOND))

The OVERLAPS predicate in jOOQ

jOOQ supports the OVERLAPS predicate on row value expressions of degree 2. The following methods are contained in org.jooq.Row2:

Condition overlaps(T1 t1, T2 t2);
Condition overlaps(Field<T1> t1, Field<T2> t2);
Condition overlaps(Row2<T1, T2> row);

This allows for expressing the above predicates as such:

// The date range tuples version
row(Date.valueOf('2010-01-01'), Date.valueOf('2010-01-03')).overlaps(Date.valueOf('2010-01-02'), Date.valueOf('2010-01-04'))

// The INTERVAL tuples version
row(Date.valueOf('2010-01-01'), new DayToSecond(2)).overlaps(Date.valueOf('2010-01-02'), new DayToSecond(2))

jOOQ's extensions to the standard

Unlike the standard (or any database implementing the standard), jOOQ also supports the OVERLAPS predicate for comparing arbitrary row vlaue expressions of degree 2. For instance, (1, 3) OVERLAPS (2, 4) will yield true in jOOQ. This is emulated as such

-- This predicate
(A, B) OVERLAPS (C, D)

-- can be emulated as such
(C <= B) AND (A <= D)

A popular approach to querying database tables is called Query by Example, meaning that an "example" of a result record is provided instead of a formal query:

-- example book record:
ID          : 
AUTHOR_ID   : 1
TITLE       :
PUBLISHED_IN: 1970
LANGUAGE_ID : 1
-- Corresponding query
SELECT *
FROM book
WHERE author_id = 1
AND published_in = 1970
AND language_id = 1

The translation from an example record to a query is fairly straight-forward:

  • If a record attribute is set to a value, then that value is used for an equality predicate
  • If a record attribute is not set, then that attribute is not used for any predicates

jOOQ knows a simple API called DSL.condition(Record), which translates a org.jooq.Record to a org.jooq.Condition:

BookRecord book = new BookRecord();
book.setAuthorId(1);
book.setPublishedIn(1970);
book.setLanguageId(1);

// Using the explicit condition() API
Result<BookRecord> books1 =
DSL.using(configuration)
   .selectFrom(BOOK)
   .where(condition(book))
   .fetch();
   
// Using the convenience API on DSLContext
Result<BookRecord> books2 = DSL.using(configuration).fetchByExample(book);

The latter API call makes use of the convenience API DSLContext.fetchByExample(TableRecord).

In most cases, table expressions, column expressions, and conditional expressions as introduced in the previous chapters will be embedded into different SQL statement clauses as if the statement were a static SQL statement (e.g. in a view or stored procedure):

create.select(
          AUTHOR.FIRST_NAME.concat(AUTHOR.LAST_NAME),
          count()
      .from(AUTHOR)
      .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
      .groupBy(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME)
      .orderBy(count().desc())
      .fetch();

It is, however, interesting to think of all of the above expressions as what they are: expressions. And as such, nothing keeps users from extracting expressions and referencing them from outside the statement. The following statement is exactly equivalent:

SelectField<?>[] select = {
    AUTHOR.FIRST_NAME.concat(AUTHOR.LAST_NAME),
    count()
};
Table<?> from = AUTHOR.join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID));
GroupField[] groupBy = { AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME };
SortField<?>[] orderBy = { count().desc() };

create.select(select)
      .from(from)
      .groupBy(groupBy)
      .orderBy()
      .fetch();

Each individual expression, and collection of expressions can be seen as an independent entity that can be

  1. Constructed dynamically
  2. Reused across queries

Dynamic construction is particularly useful in the case of the WHERE clause, for dynamic predicate building. For instance:

public Condition condition(HttpServletRequest request) {
    Condition result = trueCondition();
    
    if (request.getParameter("title") != null)
        result = result.and(BOOK.TITLE.like("%" + request.getParameter("title") + "%"));
        
    if (request.getParameter("author") != null)
        result = result.and(BOOK.AUTHOR_ID.in(
            selectOne().from(AUTHOR).where(
                    AUTHOR.FIRST_NAME.like("%" + request.getParameter("author") + "%")
                .or(AUTHOR.LAST_NAME .like("%" + request.getParameter("author") + "%"))
            )
        ));
    
    return result;
}

// And then:
create.select()
      .from(BOOK)
      .where(condition(httpRequest))
      .fetch();

The dynamic SQL building power may be one of the biggest advantages of using a runtime query model like the one offered by jOOQ. Queries can be created dynamically, of arbitrary complexity. In the above example, we've just constructed a dynamic WHERE clause. The same can be done for any other clauses, including dynamic FROM clauses (dynamic JOINs), or adding additional WITH clauses as needed.

A DSL is a nice thing to have, it feels "fluent" and "natural", especially if it models a well-known language, such as SQL. But a DSL is always expressed in a host language (Java in this case), which was not made for exactly the same purposes as its hosted DSL. If it were, then jOOQ would be implemented on a compiler-level, similar to LINQ in .NET. But it's not, and so, the DSL is limited by language constraints of its host language. We have seen many functionalities where the DSL becomes a bit verbose. This can be especially true for:

You'll probably find other examples. If verbosity scares you off, don't worry. The verbose use-cases for jOOQ are rather rare, and when they come up, you do have an option. Just write SQL the way you're used to!

jOOQ allows you to embed SQL as a String into any supported statement in these contexts:

The DSL plain SQL API

Plain SQL API methods are usually overloaded in three ways. Let's look at the condition query part constructor:

// Construct a condition without bind values
// Example: condition("a = b")
Condition condition(String sql);

// Construct a condition with bind values
// Example: condition("a = ?", 1);
Condition condition(String sql, Object... bindings);

// Construct a condition taking other jOOQ object arguments
// Example: condition("a = {0}", val(1));
Condition condition(String sql, QueryPart... parts);

Both the bind value and the query part argument overloads make use of jOOQ's plain SQL templating language.

Please refer to the org.jooq.impl.DSL Javadoc for more details. The following is a more complete listing of plain SQL construction methods from the DSL:

// A condition
Condition condition(String sql);
Condition condition(String sql, Object... bindings);
Condition condition(String sql, QueryPart... parts);

// A field with an unknown data type
Field<Object> field(String sql);
Field<Object> field(String sql, Object... bindings);
Field<Object> field(String sql, QueryPart... parts);

// A field with a known data type
<T> Field<T> field(String sql, Class<T> type);
<T> Field<T> field(String sql, Class<T> type, Object... bindings);
<T> Field<T> field(String sql, Class<T> type, QueryPart... parts);
<T> Field<T> field(String sql, DataType<T> type);
<T> Field<T> field(String sql, DataType<T> type, Object... bindings);
<T> Field<T> field(String sql, DataType<T> type, QueryPart... parts);

// A field with a known name (properly escaped)
Field<Object> field(Name name);
<T> Field<T>  field(Name name, Class<T> type);
<T> Field<T>  field(Name name, DataType<T> type);

// A function
<T> Field<T> function(String name, Class<T> type, Field<?>... arguments);
<T> Field<T> function(String name, DataType<T> type, Field<?>... arguments);

// A table
Table<?> table(String sql);
Table<?> table(String sql, Object... bindings);
Table<?> table(String sql, QueryPart... parts);

// A table with a known name (properly escaped)
Table<Record> table(Name name);

// A query without results (update, insert, etc)
Query query(String sql);
Query query(String sql, Object... bindings);
Query query(String sql, QueryPart... parts);

// A query with results
ResultQuery<Record> resultQuery(String sql);
ResultQuery<Record> resultQuery(String sql, Object... bindings);
ResultQuery<Record> resultQuery(String sql, QueryPart... parts);

// A query with results. This is the same as resultQuery(...).fetch();
Result<Record> fetch(String sql);
Result<Record> fetch(String sql, Object... bindings);
Result<Record> fetch(String sql, QueryPart... parts);

Apart from the general factory methods, plain SQL is also available in various other contexts. For instance, when adding a .where("a = b") clause to a query. Hence, there exist several convenience methods where plain SQL can be inserted usefully. This is an example displaying all various use-cases in one single query:

// You can use your table aliases in plain SQL fields
// As long as that will produce syntactically correct SQL
Field<?> LAST_NAME    = create.field("a.LAST_NAME");

// You can alias your plain SQL fields
Field<?> COUNT1       = create.field("count(*) x");

// If you know a reasonable Java type for your field, you
// can also provide jOOQ with that type
Field<Integer> COUNT2 = create.field("count(*) y", Integer.class);

       // Use plain SQL as select fields
create.select(LAST_NAME, COUNT1, COUNT2)

       // Use plain SQL as aliased tables (be aware of syntax!)
      .from("author a")
      .join("book b")

       // Use plain SQL for conditions both in JOIN and WHERE clauses
      .on("a.id = b.author_id")

       // Bind a variable in plain SQL
      .where("b.title != ?", "Brida")

       // Use plain SQL again as fields in GROUP BY and ORDER BY clauses
      .groupBy(LAST_NAME)
      .orderBy(LAST_NAME)
      .fetch();

Important things to note about plain SQL!

There are some important things to keep in mind when using plain SQL:

  • jOOQ doesn't know what you're doing. You're on your own again!
  • You have to provide something that will be syntactically correct. If it's not, then jOOQ won't know. Only your JDBC driver or your RDBMS will detect the syntax error.
  • You have to provide consistency when you use variable binding. The number of ? must match the number of variables
  • Your SQL is inserted into jOOQ queries without further checks. Hence, jOOQ can't prevent SQL injection.

The plain SQL API, as documented in the previous chapter, supports a string templating mini-language that allows for constructing complex SQL string content from smaller parts. A simple example can be seen below, e.g. when looking for support for one of PostgreSQL's various vendor-specific operator types:

ARRAY[1,4,3] && ARRAY[2,1]
condition("{0} && {1}", array1, array2);

Such a plain SQL template always consists of two things:

  • The SQL string fragment
  • A set of org.jooq.QueryPart arguments, which are expected to be embedded in the SQL string

The SQL string may reference the arguments by 0-based indexing. Each argument may be referenced several times. For instance, SQLite's emulation of the REPEAT(string, count) function may look like this:

Field<Integer> count = val(3);
Field<String> string = val("abc");
field("replace(substr(quote(zeroblob(({0} + 1) / 2)), 3, {0}), '0', {1})", String.class, count, string);
//                                     ^                  ^          ^                   ^^^^^  ^^^^^^
//                                     |                  |          |                     |       |
// argument "count" is repeated twice: \------------------+----------|---------------------/       |
// argument "string" is used only once:                              \-----------------------------/

For convenience, there is also a DSL.list(QueryPart...) API that allows for wrapping a comma-separated list of query parts in a single template argument:

Field<String> a = val("a");
Field<String> b = val("b");
Field<String> c = val("c");

// These two produce the same result:
condition("my_column IN ({0}, {1}, {2})", a, b, c); // Using distinct template arguments
condition("my_column IN ({0})", list(a, b, c));    // Using a single template argument

Parsing rules

When processing these plain SQL templates, a mini parser is run that handles things like

  • String literals
  • Quoted names
  • Comments
  • JDBC escape sequences

The above are recognised by the templating engine and contents inside of them are ignored when replacing numbered placeholders and/or bind variables. For instance:

query(
  "SELECT /* In a comment, this is not a placeholder: {0}. And this is not a bind variable: ? */ title AS `title {1} ?` " +
  "-- Another comment without placeholders: {2} nor bind variables: ?" +
  "FROM book " +
  "WHERE title = 'In a string literal, this is not a placeholder: {3}. And this is not a bind variable: ?'"
);

The above query does not contain any numbered placeholders nor bind variables, because the tokens that would otherwise be searched for are contained inside of comments, string literals, or quoted names.

Goal

Historically, jOOQ implements an internal domain-specific language in Java, which generates SQL (an external domain-specific language) for use with JDBC. The jOOQ API is built from two parts: The DSL and the model API where the DSL API adds lexical convenience for programmers on top of the model API, which is really just a SQL expression tree, similar to what a SQL parser does inside of any database.

With this parser, the whole set of jOOQ functionality will now also be made available to anyone who is not using jOOQ directly, including JDBC and/or JPA users, e.g. through the parsing connection, which proxies all JDBC Connection calls to the jOOQ parser before forwarding them to the database, or through the DSLContext.parser() API, which allows for a more low-level access to the parser directly, e.g. for tool building on top of jOOQ.

The possibilities are endless, including standardised, SQL string based database migrations that work on any SQLDialect that is supported by jOOQ.

Example

This parser API allows for parsing an arbitrary SQL string fragment into a variety of jOOQ API elements:

The parser is able to parse any unspecified dialect to produce a jOOQ representation of the SQL expression, for instance:

ResultQuery<?> query = 
DSL.using(configuration)
   .parser()
   .parseResultQuery("SELECT * FROM (VALUES (1, 'a'), (2, 'b')) t(a, b)")

The above SQL query is valid standard SQL and runs out of the box on PostgreSQL and SQL Server, among others. The jOOQ ResultQuery that is generated from this SQL string, however, will also work on any other database, as jOOQ can emulate the two interesting SQL features being used here:

The query might be rendered as follows on the H2 database, which supports VALUES(), but not derived column lists:

select 
  t.a, 
  t.b
from (
  (
    select 
      null a, 
      null b
    where 1 = 0
  )
  union all (
    select *
    from (values
      (1, 'a'),
      (2, 'b')
    ) t
  )
) t;

Or like this on Oracle, which supports neither feature:

select 
  t.a, 
  t.b
from (
  (
    select 
      null a, 
      null b
    from dual
    where 1 = 0
  )
  union all (
    select *
    from (
      (
        select 
          1, 
          'a'
        from dual
      )
      union all (
        select 
          2, 
          'b'
        from dual
      )
    ) t
  )
) t;

The Parser API can be used as a translator between source and target dialects programmatically, as we've seen in the previous section about the parser API. This functionality can also usefully be accessed on the command line as shown below:

$ java -cp jooq-3.11.7.jar org.jooq.ParserCLI -h
Usage:
  -f / --formatted                        Format output SQL
  -h / --help                             Display this help
  -k / --keyword    <RenderKeywordStyle>  Specify the output keyword style (org.jooq.conf.RenderKeywordStyle)
  -i / --identifier <RenderNameStyle>     Specify the output identifier style (org.jooq.conf.RenderNameStyle)
  -t / --to-dialect <SQLDialect>          Specify the output dialect (org.jooq.SQLDialect)
  -s / --sql        <String>              Specify the input SQL string

$ java -cp jooq-3.11.7.jar org.jooq.ParserCLI -t ORACLE -s "SELECT substring('abcde', 2, 3)"
select substr('abcde', 2, 3) from dual;

Another way to use this API is the https://www.jooq.org/translate website.

The existing implementation of the SQL parser is a hand-written, recursive descent parser. There are great advantages of this approach over formal grammar-based, generated parsers (e.g. by using ANTLR). These advantages are, among others:

  • They can be tuned easily for performance
  • They are very simple and easy to maintain
  • It's easy to implement corner cases of the grammar, which might require context (that's a big plus with SQL)
  • It's the easiest way to bind a grammar to an existing backing expression tree implementation (which is what jOOQ really is)

Nevertheless, there is a grammar available for documentation purposes and it is included in the manual here:

(The layout of the grammar and the grammar itself is still work in progress)

batch ::=

; query

query ::=

ddlStatement dmlStatement blockStatement

ddlStatement ::=

alterTableStatement alterIndexStatement alterSchemaStatement alterSequenceStatement alterSessionStatement alterViewStatement commentStatement createTableStatement createIndexStatement createSchemaStatement createSequenceStatement createViewStatement dropTableStatement dropIndexStatement dropViewStatement dropSequenceStatement dropSchemaStatement grantStatement renameStatement revokeStatement setCatalogStatement setSchemaStatement truncateStatement useStatement

dmlStatement ::=

deleteStatement insertStatement mergeStatement selectStatement updateStatement

proceduralStatement ::=

query nullStatement

blockStatement ::=

EXECUTE BLOCK AS BEGIN proceduralStatement ; proceduralStatement ; END DO stringLiteral

nullStatement ::=

NULL

alterTableStatement ::=

ALTER TABLE IF EXISTS tableName ADD CONSTRAINT constraintName constraint ADD constraint ADD COLUMN column ADD ( CONSTRAINT constraintName constraint constraint column , CONSTRAINT constraintName constraint constraint column ) ALTER MODIFY COLUMN identifier SET DATA TYPE dataType NOT NULL SET DROP NOT NULL RENAME TO AS identifier COMMENT = stringLiteral DROP COLUMN identifier CASCADE RESTRICT DROP CONSTRAINT constraintName RENAME COLUMN INDEX CONSTRAINT identifier TO AS identifier

alterIndexStatement ::=

ALTER INDEX IF EXISTS indexName RENAME TO AS indexName

alterSchemaStatement ::=

ALTER SCHEMA IF EXISTS schemaName RENAME TO AS schemaName

alterSequenceStatement ::=

ALTER SEQUENCE IF EXISTS sequenceName RENAME TO AS sequenceName RESTART WITH unsignedInteger SET GENERATOR sequenceName TO unsignedInteger

alterSessionStatement ::=

ALTER SESSION SET CURRENT_SCHEMA = schemaName

alterViewStatement ::=

ALTER VIEW IF EXISTS tableName RENAME TO AS tableName

commentStatement ::=

COMMENT ON COLUMN fieldName TABLE tableName VIEW tableName IS stringLiteral

createTableStatement ::=

CREATE GLOBAL TEMPORARY TABLE IF NOT EXISTS tableName AS select ( CONSTRAINT constraintName constraint constraint index column , CONSTRAINT constraintName constraint constraint index column ) ON COMMIT DELETE ROWS DROP PRESERVE ROWS COMMENT = stringLiteral

createIndexStatement ::=

CREATE UNIQUE INDEX IF NOT EXISTS indexName ON tableName ( sortFields ) INCLUDE ( identifiers ) WHERE condition

createSchemaStatement ::=

CREATE SCHEMA IF NOT EXISTS schemaName

createSequenceStatement ::=

CREATE SEQUENCE GENERATOR IF NOT EXISTS sequenceName

createViewStatement ::=

CREATE OR ALTER REPLACE VIEW IF NOT EXISTS tableName ( fieldNames ) AS select

dropTableStatement ::=

DROP TEMPORARY TABLE IF EXISTS tableName CASCADE RESTRICT

dropIndexStatement ::=

DROP INDEX IF EXISTS indexName ON tableName

dropViewStatement ::=

DROP VIEW IF EXISTS tableName

dropSequenceStatement ::=

DROP SEQUENCE GENERATOR IF EXISTS sequenceName

dropSchemaStatement ::=

DROP SCHEMA IF EXISTS schemaName CASCADE RESTRICT

renameStatement ::=

RENAME COLUMN fieldName TO AS fieldName INDEX indexName TO AS indexName SCHEMA schemaName TO AS schemaName SEQUENCE sequenceName TO AS sequenceName VIEW tableName TO AS tableName TABLE tableName TO AS tableName

setCatalogStatement ::=

SET CATALOG catalogName

setSchemaStatement ::=

SET CURRENT SCHEMA CURRENT SQLID = schemaName stringLiteral

useStatement ::=

USE catalogName schemaName

truncateStatement ::=

TRUNCATE TABLE tableName CONTINUE IDENTITY RESTART IDENTITY CASCADE RESTRICT

grantStatement ::=

GRANT SELECT INSERT UPDATE DELETE ON tableName TO userName roleName PUBLIC WITH GRANT OPTION

revokeStatement ::=

REVOKE GRANT OPTION FOR SELECT INSERT UPDATE DELETE ON tableName FROM userName roleName PUBLIC

selectStatement ::=

select

insertStatement ::=

with INSERT INS INTO tableName ( identifiers ) values DEFAULT VALUES SET setClauses select ON DUPLICATE KEY UPDATE SET setClauses ON DUPLICATE KEY IGNORE ON CONFLICT ON CONSTRAINT constraintName ( fieldNames ) DO NOTHING UPDATE SET setClauses WHERE condition RETURNING * fields

values ::=

VALUES ( fields ) , ( fields )

updateStatement ::=

with UPDATE UPD tableName SET setClauses WHERE condition RETURNING * fields

setClauses ::=

, setClause

setClause ::=

fieldName = field

deleteStatement ::=

with DELETE DEL FROM tableName WHERE condition RETURNING * fields

mergeStatement ::=

with MERGE INTO tableName AS identifier USING ( select ) AS identifier ON condition WHEN MATCHED AND condition THEN UPDATE SET setClauses WHERE condition WHEN NOT MATCHED AND condition THEN INSERT ( identifiers ) VALUES ( fields ) WHERE condition

column ::=

identifier dataType NOT NULL DEFAULT ON NULL concat ON UPDATE concat GENERATED ALWAYS BY DEFAULT ON NULL AS IDENTITY ( identity ) PRIMARY KEY UNIQUE KEY INDEX CHECK ( condition ) REFERENCES constraintReferenceSpecification AUTO_INCREMENT AUTOINCREMENT IDENTITY ( signedInteger , signedInteger ) COMMENT stringLiteral

index ::=

KEY INDEX identifier ( sortFields )

constraint ::=

PRIMARY KEY ( fieldNames ) UNIQUE KEY INDEX ( fieldNames ) FOREIGN KEY ( fieldNames ) REFERENCES constraintReferenceSpecification CHECK ( condition ) ENABLE

constraintReferenceSpecification ::=

tableName ( fieldNames ) ON DELETE UPDATE CASCADE NO ACTION RESTRICT SET DEFAULT SET NULL

identity ::=

START WITH LIMIT VALUE unsignedInteger INCREMENT BY unsignedInteger MAXVALUE unsignedInteger NOMAXVALUE MINVALUE unsignedInteger NOMINVALUE CACHE unsignedInteger NOCACHE CYCLE NOCYCLE ORDER NOORDER

with ::=

WITH RECURSIVE , commonTableExpression

commonTableExpression ::=

identifier ( identifiers ) AS ( select )

select ::=

with queryExpressionBody orderBy seekFetch offsetFetch forUpdate values

queryExpressionBody ::=

queryTerm UNION EXCEPT MINUS ALL DISTINCT queryTerm

queryTerm ::=

queryPrimary INTERSECT ALL DISTINCT queryTerm

queryPrimary ::=

( select ) SELECT SEL distinct top selectList INTO tableName tableExpression

distinct ::=

DISTINCT UNIQUE ON ( fields ) ALL

top ::=

TOP unsignedInteger PERCENT START AT unsignedInteger WITH TIES SKIP unsignedInteger FIRST unsignedInteger

selectList ::=

* selectField

selectField ::=

field AS identifier

tableExpression ::=

FROM tables WHERE condition connectBy groupBy HAVING condition WINDOW windows

connectBy ::=

START WITH condition CONNECT BY NOCYCLE condition CONNECT BY NOCYCLE condition START WITH condition

groupBy ::=

GROUP BY () ROLLUP ( fields ) CUBE ( fields ) GROUPING SETS ( , groupingSet ) fields WITH ROLLUP

groupingSet ::=

( fields )

windows ::=

, window

window ::=

identifier AS ( windowSpecification )

windowSpecification ::=

PARTITION BY fields ORDER BY sortFields ROWS RANGE BETWEEN rangeBound AND rangeBound rangeBound

orderBy ::=

ORDER SIBLINGS BY sortFields

seekFetch ::=

SEEK , field FETCH FIRST NEXT unsignedInteger PERCENT ROW ROWS ONLY WITH TIES LIMIT unsignedInteger PERCENT WITH TIES

offsetFetch ::=

OFFSET unsignedInteger ROW ROWS FETCH FIRST NEXT unsignedInteger PERCENT ROW ROWS ONLY WITH TIES LIMIT unsignedInteger PERCENT WITH TIES LIMIT unsignedInteger PERCENT WITH TIES OFFSET unsignedInteger , unsignedInteger

forUpdate ::=

FOR SHARE FOR UPDATE OF fields NOWAIT WAIT unsignedInteger SKIP LOCKED

sortFields ::=

, sortField

sortField ::=

field ASC DESC NULLS FIRST NULLS LAST

tables ::=

, table

table ::=

lateral unqualifiedJoin innerJoin outerJoin semiAntiJoin

unqualifiedJoin ::=

CROSS JOIN CROSS APPLY OUTER APPLY NATURAL LEFT RIGHT OUTER JOIN lateral

innerJoin ::=

INNER JOIN STRAIGHT_JOIN table joinQualification

outerJoin ::=

LEFT RIGHT FULL OUTER JOIN table PARTITION BY ( fields ) joinQualification

semiAntiJoin ::=

LEFT SEMI ANTI JOIN table joinQualification

lateral ::=

LATERAL tableFactor tableFactor

tableFactor ::=

tableName versions correlationName tableHints ( table ) correlationName ( select ) correlationName tableFunction correlationName UNNEST ( field ) values correlationName

tableFunction ::=

GENERATE_SERIES ( sum , sum , sum )

tableHints ::=

WITH ( , tableHint )

pivot ::=

todo

versions ::=

VERSIONS BETWEEN SCN TIMESTAMP MINVALUE field AND MAXVALUE field AS OF SCN TIMESTAMP

joinQualification ::=

ON condition USING ( identifiers )

correlationName ::=

AS identifier ( identifiers )

fields ::=

, field

field ::=

or

condition ::=

or

or ::=

OR and

and ::=

AND not

not ::=

NOT predicate

predicate ::=

EXISTS ( select ) concat comparator ALL ANY SOME ( select ) concat IS NOT NULL DISTINCT FROM concat IN ( select fields ) BETWEEN SYMMETRIC concat AND concat LIKE concat ESCAPE characterLiteral @> concat concat *= concat concat =* concat row2 OVERLAPS row2

row2 ::=

ROW ( field , field )

concat ::=

|| collated

collated ::=

sum COLLATE collation

sum ::=

factor + - factor

factor ::=

exp * / % exp

exp ::=

^ unaryOps

unaryOps ::=

+ - term (+) :: dataType

term ::=

: identifier ? stringLiteral ANY ( field ) filter over ACOS ( sum ) ARRAY_AGG ( DISTINCT field ORDER BY sortFields ) filter over ASCII ( field ) ASIN ( sum ) ATAN ( sum ) ATN2 ATAN2 ( sum , sum ) ARRAY [ fields ] AVG ( DISTINCT ALL field ) keep filter over BIN_AND ( field , field ) BIN_SHL ( field , field ) BIN_SHR ( field , field ) BIN_OR ( field , field ) BIN_XOR ( field , field ) BITAND ( field , field ) BITOR ( field , field ) BITXOR ( field , field ) BIT_AND ( field , field ) BIT_COUNT ( field ) BIT_LENGTH ( field ) BIT_NAND ( field , field ) BIT_NOR ( field , field ) BIT_NOT ( field , field ) BIT_OR ( field , field ) BIT_XNOR ( field , field ) BITXOR ( field , field ) BIT_XOR ( field , field ) case CAST ( field AS castDataType ) CEIL CEILING ( sum ) CHARINDEX ( field , field ) CHAR_LENGTH ( field ) CHOOSE ( , field ) COALESCE ( fields ) CONCAT ( fields ) CONVERT ( dataType , field ) COS ( sum ) COSH ( sum ) COT ( sum ) COTH ( sum ) COUNT ( * DISTINCT ALL field ) keep filter over CUME_DIST ( ) over ( fields ) withinGroup CURRVAL ( name stringLiteral ) CURRENT_DATE CURRENT_SCHEMA CURRENT_TIME CURRENT_TIMESTAMP CURRENT_USER dateLiteral DATEADD ( datePart , field , field ) DATE_TRUNC ( stringLiteral , field ) DAY ( field ) DECODE ( field , field , , field ) DENSE_RANK ( ) over ( fields ) withinGroup DEG DEGREE ( sum ) EXTRACT ( datePart FROM field ) EXP ( sum ) EVERY ( field ) filter over FLOOR ( sum ) FIELD ( field , , field ) FIRST_VALUE ( field ) over GETDATE ( ) GREATEST ( fields ) GROUP_CONCAT ( DISTINCT field ORDER BY sortFields SEPARATOR stringLiteral ) GROUP_ID ( ) GROUPING_ID ( fields ) GROUPING ( fields ) HOUR ( field ) IFNULL ( field , field ) INSTR ( field , field ) intervalLiteral IIF ( condition , field , field ) ISNULL ( field , field ) LOWER LCASE ( field ) LPAD ( field , field , field ) LTRIM ( field ) LEFT ( field , field ) LEN ( field ) LENGTH ( field ) LN ( sum ) LOG ( sum , unsignedInteger ) LEVEL LEAST ( fields ) LEAD ( field , unsignedInteger , field ) over LAG ( field , unsignedInteger , field ) over LAST_VALUE ( field ) over LISTAGG ( field , stringLiteral ) withinGroup over MIN ( DISTINCT ALL field ) keep filter over MAX ( DISTINCT ALL field ) keep filter over MEDIAN ( field ) filter over MOD ( field , field ) MODE ( ) withinGroup over MONTH ( field ) MINUTE ( field ) MID ( field , field , field ) MD5 ( field ) NVL ( field , field ) NVL2 ( field , field , field ) NULLIF ( field , field ) NTILE ( unsignedInteger ) over NTH_VALUE ( field , unsignedInteger ) over NEXT VALUE FOR sequenceName NEXTVAL ( name stringLiteral ) OCTET_LENGTH ( field ) POSITION ( field IN field ) PERCENT_RANK ( ) over ( fields ) withinGroup PERCENTILE_CONT PERCENTILE_DISC ( unsignedNumericLiteral ) withinGroup over POW POWER ( field , field ) PRIOR concat REGR_SLOPE REGR_INTERCEPT REGR_COUNT REGR_R2 REGR_AVGX REGR_AVGY REGR_SXX REGR_SYY REGR_SXY ( sum , sum ) REPLACE OREPLACE ( field , field , field ) REPEAT ( field , field ) REVERSE ( field ) RPAD ( field , field , field ) RTRIM ( field ) RIGHT ( field , field ) ROW_NUMBER ( ) over RANK ( ) over ( fields ) withinGroup ROUND ( field , unsignedInteger ) ROWNUM RAD RADIAN ( sum ) ROW ( fields ) SUBSTR SUBSTRING ( field , sum , sum ) SECOND ( field ) SHL SHIFTLEFT ( field , field ) SHR SHIFTRIGHT ( field , field ) SIGN ( field ) SQR SQRT ( sum ) SIN ( sum ) SINH ( sum ) SPACE ( field ) STDDEV_POP ( field ) over STDDEV_SAMP ( field ) over STR_REPLACE ( field , field , field ) SUBSTRING ( field FROM sum FOR sum ) SUM ( DISTINCT ALL field ) keep filter TAN ( sum ) TANH ( sum ) timeLiteral timestampLiteral TO_CHAR ( field ) TO_DATE ( field , field ) TO_NUMBER ( field ) TO_TIMESTAMP ( field , field ) TRANSLATE OTRANSLATE ( field , field , field ) TRIM ( field ) TRUNC ( field , stringLiteral ) TRUNC ( sum , sum ) truthValue UPPER UCASE ( field ) VAR_POP ( field ) over VAR_SAMP ( field ) over WIDTH_BUCKET ( field , field , field , field ) binaryLiteral YEAR ( field ) unsignedNumericLiteral ( select ) ( fields ) { d stringLiteral } { t stringLiteral } { fn term } { ts stringLiteral }

truthValue ::=

TRUE FALSE NULL

datePart ::=

YEAR MONTH DAY HOUR MINUTE SECOND

keep ::=

KEEP ( DENSE_RANK FIRST LAST ORDER BY sortFields )

filter ::=

FILTER ( WHERE condition )

over ::=

FROM FIRST FROM LAST RESPECT NULLS IGNORE NULLS OVER identifier ( windowSpecification )

withinGroup ::=

WITHIN GROUP ( ORDER BY sortFields )

rangeBound ::=

UNBOUNDED unsignedInteger PRECEDING FOLLOWING CURRENT ROW

case ::=

CASE WHEN condition THEN field field WHEN field THEN field ELSE field END

comparator ::=

= != <> >= > <=> <= <

castDataType ::=

dataType SIGNED INTEGER UNSIGNED INTEGER

dataType ::=

BIGINT UNSIGNED BINARY ( unsignedInteger ) BIT ( unsignedInteger ) BLOB ( unsignedInteger ) BOOLEAN CHAR ( unsignedInteger ) BYTE CHAR COLLATE collationName CHARACTER ( unsignedInteger ) BYTE CHAR COLLATE collationName CLOB ( unsignedInteger ) COLLATE collationName DATE DECIMAL ( unsignedInteger , unsignedInteger ) DOUBLE PRECISION ( unsignedInteger , unsignedInteger ) ENUM ( stringLiteral , stringLiteral ) COLLATE collationName FLOAT ( unsignedInteger , unsignedInteger ) INT ( unsignedInteger ) UNSIGNED INTEGER ( unsignedInteger ) UNSIGNED LONGBLOB LONGTEXT COLLATE collationName LONG NVARCHAR ( unsignedInteger ) COLLATE collationName LONG VARBINARY ( unsignedInteger ) LONG VARCHAR ( unsignedInteger ) COLLATE collationName MEDIUMBLOB MEDIUMINT ( unsignedInteger ) UNSIGNED MEDIUMTEXT COLLATE collationName NCHAR ( unsignedInteger ) COLLATE collationName NCLOB COLLATE collationName NUMBER ( unsignedInteger , unsignedInteger ) NUMERIC ( unsignedInteger , unsignedInteger ) NVARCHAR ( unsignedInteger ) COLLATE collationName REAL ( unsignedInteger , unsignedInteger ) SERIAL SERIAL4 SERIAL8 SET ( stringLiteral , stringLiteral ) COLLATE collationName SMALLINT ( unsignedInteger ) UNSIGNED TEXT ( unsignedInteger ) COLLATE collationName TIMESTAMP ( unsignedInteger ) WITH WITHOUT TIME ZONE TIMESTAMPTZ ( unsignedInteger ) TIME ( unsignedInteger ) WITH WITHOUT TIME ZONE TIMETZ ( unsignedInteger ) TINYBLOB TINYINT ( unsignedInteger ) UNSIGNED TINYTEXT COLLATE collationName UUID VARCHAR ( unsignedInteger BYTE CHAR ) COLLATE collationName VARCHAR2 ( unsignedInteger ) BYTE CHAR COLLATE collationName CHARACTER VARYING ( unsignedInteger ) BYTE CHAR COLLATE collationName VARBINARY ( unsignedInteger )

constraintName ::=

identifier

catalogName ::=

name

schemaName ::=

name

tableName ::=

name

indexName ::=

name

sequenceName ::=

name

userName ::=

name

roleName ::=

name

fieldNames ::=

, fieldName

fieldName ::=

name

collation ::=

name

name ::=

. identifier

stringLiteral ::=

' character ' q'[ characters ]' q'{ characters }' q'( characters )' q'< characters >' q' nonSpaceCharacter characters nonSpaceCharacter '

characterLiteral ::=

' character '

dateLiteral ::=

DATE stringLiteral

timeLiteral ::=

TIME stringLiteral

timestampLiteral ::=

TIMESTAMP stringLiteral

intervalLiteral ::=

INTERVAL stringLiteral

signedInteger ::=

todo

unsignedInteger ::=

todo

unsignedNumericLiteral ::=

todo

identifiers ::=

, identifier

identifier ::=

identifierStart identifierPart " doubleQuotedIdentifierPart doubleQuotedIdentifierPart " ` backtickQuotedIdentifierPart backtickQuotedIdentifierPart ` [ brackedQuotedIdentifierPart brackedQuotedIdentifierPart ]

identifierStart ::=

todo

identifierPart ::=

todo

doubleQuotedIdentifierPart ::=

nonDoubleQuoteCharacter doubleQuote

backtickQuotedIdentifierPart ::=

nonBacktickCharacter doubleBacktick

brackedQuotedIdentifierPart ::=

nonClosingBracketCharacter doubleClosingBracket

nonDoubleQuoteCharacter ::=

todo

nonBacktickCharacter ::=

todo

nonClosingBracketCharacter ::=

todo

doubleQuote ::=

""

doubleBacktick ::=

``

doubleClosingBracket ::=

]]

The diagrams have been created with the neat RRDiagram library by Christopher Deckers.

Various SQL objects columns or tables can be referenced using names (often also called identifiers). SQL dialects differ in the way they understand names, syntactically. The differences include:

  • The permitted characters to be used in "unquoted" names
  • The permitted characters to be used in "quoted" names
  • The name quoting characters (e.g. "double quotes", `backticks`, or [brackets])
  • The standard case for case-insensitive ("unquoted") names

For the above reasons, and also to prevent an additional SQL injection risk where names might contain SQL code, jOOQ by default quotes all names in generated SQL to be sure they match what is really contained in your database. This means that the following names will be rendered

-- Unquoted name
AUTHOR.TITLE

-- MariaDB, MySQL
`AUTHOR`.`TITLE`

-- MS Access, SQL Server, Sybase ASE, Sybase SQL Anywhere
[AUTHOR].[TITLE]

-- All the others, including the SQL standard
"AUTHOR"."TITLE"

Note that you can influence jOOQ's name rendering behaviour through custom settings, if you prefer another name style to be applied.

Creating custom names

Custom, qualified or unqualified names can be created very easily using the DSL.name() constructor:

// Unqualified name
Name name = name("TITLE");

// Qualified name
Name name = name("AUTHOR", "TITLE");

Such names can be used as standalone QueryParts, or as DSL entry point for SQL expressions, like

More details about how to use names / identifiers to construct such expressions can be found in the relevant sections of the manual.

Bind values are used in SQL / JDBC for various reasons. Among the most obvious ones are:

  • Protection against SQL injection. Instead of inlining values possibly originating from user input, you bind those values to your prepared statement and let the JDBC driver / database take care of handling security aspects.
  • Increased speed. Advanced databases such as Oracle can keep execution plans of similar queries in a dedicated cache to prevent hard-parsing your query again and again. In many cases, the actual value of a bind variable does not influence the execution plan, hence it can be reused. Preparing a statement will thus be faster
  • On a JDBC level, you can also reuse the SQL string and prepared statement object instead of constructing it again, as you can bind new values to the prepared statement. jOOQ currently does not cache prepared statements, internally.

The following sections explain how you can introduce bind values in jOOQ, and how you can control the way they are rendered and bound to SQL.

JDBC only knows indexed bind values. A typical example for using bind values with JDBC is this:

try (PreparedStatement stmt = connection.prepareStatement("SELECT * FROM BOOK WHERE ID = ? AND TITLE = ?")) {

    // bind values to the above statement for appropriate indexes
    stmt.setInt(1, 5);
    stmt.setString(2, "Animal Farm");
    stmt.executeQuery();
}

With dynamic SQL, keeping track of the number of question marks and their corresponding index may turn out to be hard. jOOQ abstracts this and lets you provide the bind value right where it is needed. A trivial example is this:

create.select().from(BOOK).where(BOOK.ID.eq(5)).and(BOOK.TITLE.eq("Animal Farm")).fetch();

// This notation is in fact a short form for the equivalent:
create.select().from(BOOK).where(BOOK.ID.eq(val(5))).and(BOOK.TITLE.eq(val("Animal Farm"))).fetch();

Note the using of DSL.val() to explicitly create an indexed bind value. You don't have to worry about that index. When the query is rendered, each bind value will render a question mark. When the query binds its variables, each bind value will generate the appropriate bind value index.

Extract bind values from a query

Should you decide to run the above query outside of jOOQ, using your own java.sql.PreparedStatement, you can do so as follows:

Select<?> select = create.select().from(BOOK).where(BOOK.ID.eq(5)).and(BOOK.TITLE.eq("Animal Farm"));

// Render the SQL statement:
String sql = select.getSQL();
assertEquals("SELECT * FROM BOOK WHERE ID = ? AND TITLE = ?", sql);

// Get the bind values:
List<Object> values = select.getBindValues();
assertEquals(2, values.size());
assertEquals(5, values.get(0));
assertEquals("Animal Farm", values.get(1));

You can also extract specific bind values by index from a query, if you wish to modify their underlying value after creating a query. This can be achieved as such:

Select<?> select = create.select().from(BOOK).where(BOOK.ID.eq(5)).and(BOOK.TITLE.eq("Animal Farm"));
Param<?> param = select.getParam("2");

// You could now modify the Query's underlying bind value:
if ("Animal Farm".equals(param.getValue())) {
    param.setConverted("1984");
}

For more details about jOOQ's internals, see the manual's section about QueryParts.

Some SQL access abstractions that are built on top of JDBC, or some that bypass JDBC may support named parameters. jOOQ allows you to give names to your parameters as well, although those names are not rendered to SQL strings by default. Here is an example of how to create named parameters using the org.jooq.Param type:

// Create a query with a named parameter. You can then use that name for accessing the parameter again
Query query1 = create.select().from(AUTHOR).where(LAST_NAME.eq(param("lastName", "Poe")));
Param<?> param1 = query.getParam("lastName");

// Or, keep a reference to the typed parameter in order not to lose the <T> type information:
Param<String> param2 = param("lastName", "Poe");
Query query2 = create.select().from(AUTHOR).where(LAST_NAME.eq(param2));

// You can now change the bind value directly on the Param reference:
param2.setValue("Orwell");

The org.jooq.Query interface also allows for setting new bind values directly, without accessing the Param type:

Query query1 = create.select().from(AUTHOR).where(LAST_NAME.eq("Poe"));
query1.bind(1, "Orwell");

// Or, with named parameters
Query query2 = create.select().from(AUTHOR).where(LAST_NAME.eq(param("lastName", "Poe")));
query2.bind("lastName", "Orwell");

In order to actually render named parameter names in generated SQL, use the DSLContext.renderNamedParams() method:

create.renderNamedParams(
    create.select()
          .from(AUTHOR)
          .where(LAST_NAME.eq(
                 param("lastName", "Poe"))));
-- The named bind variable can be rendered

SELECT *
FROM AUTHOR
WHERE LAST_NAME = :lastName

Sometimes, you may wish to avoid rendering bind variables while still using custom values in SQL. jOOQ refers to that as "inlined" bind values. When bind values are inlined, they render the actual value in SQL rather than a JDBC question mark. Bind value inlining can be achieved in several ways:

In all cases, your inlined bind values will be properly escaped to avoid SQL syntax errors and SQL injection. Some examples:

// Use dedicated calls to inline() in order to specify
// single bind values to be rendered as inline values
// --------------------------------------------------
create.select()
      .from(AUTHOR)
      .where(LAST_NAME.eq(inline("Poe")))
      .fetch();

// Or render the whole query with inlined values
// --------------------------------------------------
Settings settings = new Settings()
    .withStatementType(StatementType.STATIC_STATEMENT);

// Add the settings to the Configuration
DSLContext create = DSL.using(connection, SQLDialect.ORACLE, settings);

// Run queries that omit rendering schema names
create.select()
      .from(AUTHOR)
      .where(LAST_NAME.eq("Poe"))
      .fetch();

SQL injection is serious

SQL injection is a serious problem that needs to be taken care of thoroughly. A single vulnerability can be enough for an attacker to dump your whole database, and potentially seize your database server. We've blogged about the severity of this threat on the jOOQ blog.

SQL injection happens because a programming language (SQL) is used to dynamically create arbitrary server-side statements based on user input. Programmers must take lots of care not to mix the language parts (SQL) with the user input (bind variables)

SQL injection in jOOQ

With jOOQ, SQL is usually created via a type safe, non-dynamic Java abstract syntax tree, where bind variables are a part of that abstract syntax tree. It is not possible to expose SQL injection vulnerabilities this way.

However, jOOQ offers convenient ways of introducing plain SQL strings in various places of the jOOQ API (which are annotated using org.jooq.PlainSQL since jOOQ 3.6). While jOOQ's API allows you to specify bind values for use with plain SQL, you're not forced to do that. For instance, both of the following queries will lead to the same, valid result:

// This query will use bind values, internally.
create.fetch("SELECT * FROM BOOK WHERE ID = ? AND TITLE = ?", 5, "Animal Farm");

// This query will not use bind values, internally.
create.fetch("SELECT * FROM BOOK WHERE ID = 5 AND TITLE = 'Animal Farm'");

All methods in the jOOQ API that allow for plain (unescaped, untreated) SQL contain a warning message in their relevant Javadoc, to remind you of the risk of SQL injection in what is otherwise a SQL-injection-safe API.

A org.jooq.Query and all its contained objects is a org.jooq.QueryPart. QueryParts essentially provide this functionality:

Both of these methods are contained in jOOQ's internal API's org.jooq.QueryPartInternal, which is internally implemented by every QueryPart.

The following sections explain some more details about SQL rendering and variable binding, as well as other implementation details about QueryParts in general.

Every org.jooq.QueryPart must implement the accept(Context) method to render its SQL string to a org.jooq.RenderContext. This RenderContext has two purposes:

  • It provides some information about the "state" of SQL rendering.
  • It provides a common API for constructing SQL strings on the context's internal java.lang.StringBuilder

An overview of the org.jooq.RenderContext API is given here:

// These methods are useful for generating unique aliases within a RenderContext (and thus within a Query)
String peekAlias();
String nextAlias();

// These methods return rendered SQL
String render();
String render(QueryPart part);

// These methods allow for fluent appending of SQL to the RenderContext's internal StringBuilder
RenderContext keyword(String keyword);
RenderContext literal(String literal);
RenderContext sql(String sql);
RenderContext sql(char sql);
RenderContext sql(int sql);
RenderContext sql(QueryPart part);

// These methods allow for controlling formatting of SQL, if the relevant Setting is active
RenderContext formatNewLine();
RenderContext formatSeparator();
RenderContext formatIndentStart();
RenderContext formatIndentStart(int indent);
RenderContext formatIndentLockStart();
RenderContext formatIndentEnd();
RenderContext formatIndentEnd(int indent);
RenderContext formatIndentLockEnd();

// These methods control the RenderContext's internal state
boolean       inline();
RenderContext inline(boolean inline);
boolean       qualify();
RenderContext qualify(boolean qualify);
boolean       namedParams();
RenderContext namedParams(boolean renderNamedParams);
CastMode      castMode();
RenderContext castMode(CastMode mode);
Boolean       cast();
RenderContext castModeSome(SQLDialect... dialects);

The following additional methods are inherited from a common org.jooq.Context, which is shared among org.jooq.RenderContext and org.jooq.BindContext:

// These methods indicate whether fields or tables are being declared (MY_TABLE AS MY_ALIAS) or referenced (MY_ALIAS)
boolean declareFields();
Context declareFields(boolean declareFields);
boolean declareTables();
Context declareTables(boolean declareTables);

// These methods indicate whether a top-level query is being rendered, or a subquery
boolean subquery();
Context subquery(boolean subquery);

// These methods provide the bind value indices within the scope of the whole Context (and thus of the whole Query)
int nextIndex();
int peekIndex();

An example of rendering SQL

A simple example can be provided by checking out jOOQ's internal representation of a (simplified) CompareCondition. It is used for any org.jooq.Condition comparing two fields as for example the AUTHOR.ID = BOOK.AUTHOR_ID condition here:

-- [...]
FROM AUTHOR
JOIN BOOK ON AUTHOR.ID = BOOK.AUTHOR_ID
-- [...]

This is how jOOQ renders such a condition (simplified example):

@Override
public final void accept(Context<?> context) {
    // The CompareCondition delegates rendering of the Fields to the Fields
    // themselves and connects them using the Condition's comparator operator:
    context.visit(field1)
           .sql(" ")
           .keyword(comparator.toSQL())
           .sql(" ")
           .visit(field2);
}

See the manual's sections about custom QueryParts and plain SQL QueryParts to learn about how to write your own query parts in order to extend jOOQ.

As mentioned in the previous chapter about SQL rendering, there are some elements in the org.jooq.RenderContext that are used for formatting / pretty-printing rendered SQL. In order to obtain pretty-printed SQL, just use the following custom settings:

// Create a DSLContext that will render "formatted" SQL
DSLContext pretty = DSL.using(dialect, new Settings().withRenderFormatted(true));

And then, use the above DSLContext to render pretty-printed SQL:

String sql = pretty.select(
                       AUTHOR.LAST_NAME, count().as("c"))
                   .from(BOOK)
                   .join(AUTHOR)
                   .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
                   .where(BOOK.TITLE.ne("1984"))
                   .groupBy(AUTHOR.LAST_NAME)
                   .having(count().eq(2))
                   .getSQL();
select
  "TEST"."AUTHOR"."LAST_NAME",
  count(*) "c"
from "TEST"."BOOK"
  join "TEST"."AUTHOR"
  on "TEST"."BOOK"."AUTHOR_ID" = "TEST"."AUTHOR"."ID"
where "TEST"."BOOK"."TITLE" <> '1984'
group by "TEST"."AUTHOR"."LAST_NAME"
having count(*) = 2

The section about ExecuteListeners shows an example of how such pretty printing can be used to log readable SQL to the stdout.

Every org.jooq.QueryPart must implement the accept(Context<?>) method. This Context has two purposes (among many others):

  • It provides some information about the "state" of the variable binding in process.
  • It provides a common API for binding values to the context's internal java.sql.PreparedStatement

An overview of the org.jooq.BindContext API is given here:

// This method provides access to the PreparedStatement to which bind values are bound
PreparedStatement statement();

// These methods provide convenience to delegate variable binding
BindContext bind(QueryPart part) throws DataAccessException;
BindContext bind(Collection<? extends QueryPart> parts) throws DataAccessException;
BindContext bind(QueryPart[] parts) throws DataAccessException;

// These methods perform the actual variable binding
BindContext bindValue(Object value, Class<?> type) throws DataAccessException;
BindContext bindValues(Object... values) throws DataAccessException;

Some additional methods are inherited from a common org.jooq.Context, which is shared among