Available in versions: Dev (3.19) | Latest (3.18) | 3.17 | 3.16 | 3.15 | 3.14 | 3.13 | 3.12 | 3.11 | 3.10 | 3.9
Overview
This manual is divided into six main sections:
-
Getting started with jOOQ
This section will get you started with jOOQ quickly. It contains simple explanations about what jOOQ is, what jOOQ isn't and how to set it up for the first time
-
SQL building
This section explains all about the jOOQ syntax used for building queries through the query DSL and the query model API. It explains the central factories, the supported SQL statements and various other syntax elements
-
Code generation
This section explains how to configure and use the built-in source code generator
-
SQL execution
This section will get you through the specifics of what can be done with jOOQ at runtime, in order to execute queries, perform CRUD operations, import and export data, and hook into the jOOQ execution lifecycle for debugging
-
Tools
This section is dedicated to tools that ship with jOOQ.
-
Reference
This section is a reference for elements in this manual
Table of contents
- 1.
- Preface
- 2.
- Copyright, License, and Trademarks
- 3.
- Getting started with jOOQ
- 3.1.
- How to read this manual
- 3.2.
- The sample database used in this manual
- 3.3.
- Different use cases for jOOQ
- 3.3.1.
- jOOQ as a SQL builder without code generation
- 3.3.2.
- jOOQ as a SQL builder with code generation
- 3.3.3.
- jOOQ as a SQL executor
- 3.3.4.
- jOOQ for CRUD
- 3.3.5.
- jOOQ for PROs
- 3.4.
- 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 with Flyway
- 3.4.3.
- Using jOOQ with jbang
- 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.
- Build your own
- 3.14.
- jOOQ and backwards-compatibility
- 4.
- SQL building
- 4.1.
- The query DSL type
- 4.1.1.
- DSL subclasses
- 4.2.
- The DSLContext API
- 4.2.1.
- SQL Dialect
- 4.2.2.
- SQL Dialect Family
- 4.2.3.
- Connection vs. DataSource
- 4.2.4.
- Custom data
- 4.2.5.
- Custom ExecuteListeners
- 4.2.6.
- Custom Unwrappers
- 4.2.7.
- Custom Settings
- 4.2.7.1.
- Auto-attach Records
- 4.2.7.2.
- Auto-inline bind values (new)
- 4.2.7.3.
- Backslash Escaping
- 4.2.7.4.
- Batch size
- 4.2.7.5.
- Execute Logging
- 4.2.7.6.
- Fetch Warnings
- 4.2.7.7.
- GROUP_CONCAT Configuration
- 4.2.7.8.
- Identifier style
- 4.2.7.9.
- Implicit join type
- 4.2.7.10.
- Inline Threshold
- 4.2.7.11.
- IN-list Padding
- 4.2.7.12.
- Interpreter Configuration
- 4.2.7.13.
- JDBC Flags
- 4.2.7.14.
- Keyword style
- 4.2.7.15.
- Listener Invocation Order
- 4.2.7.16.
- Locales
- 4.2.7.17.
- Map JPA Annotations
- 4.2.7.18.
- Object qualification
- 4.2.7.19.
- Optimistic Locking
- 4.2.7.20.
- Parameter name prefix
- 4.2.7.21.
- Parameter types
- 4.2.7.22.
- Parser Configuration
- 4.2.7.23.
- Reflection caching
- 4.2.7.24.
- Return all columns on store
- 4.2.7.25.
- Return Identity Value On Store
- 4.2.7.26.
- Runtime catalog, schema and table mapping
- 4.2.7.27.
- Scalar subqueries for stored functions
- 4.2.7.28.
- Statement Type
- 4.2.7.29.
- Updatable Primary Keys
- 4.2.8.
- Thread safety
- 4.3.
- The DSL API
- 4.3.1.
- Mutability (historic)
- 4.4.
- The model API
- 4.4.1.
- Design
- 4.4.2.
- Traversal
- 4.4.3.
- Replacement
- 4.4.3.1.
- Listening Replacer (new)
- 4.4.3.2.
- Decomposing Replacer (new)
- 4.4.4.
- The historic model API
- 4.5.
- SQL Statements (DML)
- 4.5.1.
- The WITH clause
- 4.5.2.
- The WITH RECURSIVE clause
- 4.5.3.
- The SELECT statement
- 4.5.3.1.
- SELECT clause
- 4.5.3.1.1.
- Projection type safety
- 4.5.3.1.2.
- SelectField
- 4.5.3.1.3.
- Tables as SelectField
- 4.5.3.1.4.
- SELECT *
- 4.5.3.1.5.
- SELECT * EXCEPT (...)
- 4.5.3.1.6.
- SELECT DISTINCT
- 4.5.3.1.7.
- SELECT DISTINCT ON
- 4.5.3.1.8.
- Convenience methods
- 4.5.3.2.
- FROM clause
- 4.5.3.3.
- JOIN operator
- 4.5.3.4.
- Implicit path JOIN
- 4.5.3.5.
- WHERE clause
- 4.5.3.6.
- CONNECT BY clause
- 4.5.3.7.
- GROUP BY clause
- 4.5.3.7.1.
- GROUP BY columns
- 4.5.3.7.2.
- GROUP BY tables
- 4.5.3.7.3.
- GROUP BY ROLLUP
- 4.5.3.7.4.
- GROUP BY CUBE
- 4.5.3.7.5.
- GROUP BY GROUPING SETS
- 4.5.3.7.6.
- GROUP BY empty grouping set
- 4.5.3.8.
- HAVING clause
- 4.5.3.9.
- WINDOW clause
- 4.5.3.10.
- QUALIFY clause
- 4.5.3.11.
- ORDER BY clause
- 4.5.3.12.
- LIMIT .. OFFSET clause
- 4.5.3.13.
- WITH TIES clause
- 4.5.3.14.
- SEEK clause
- 4.5.3.15.
- FOR clause
- 4.5.3.16.
- FOR UPDATE clause
- 4.5.3.17.
- Set operations
- 4.5.3.17.1.
- Type safety
- 4.5.3.17.2.
- Projection rowtype
- 4.5.3.17.3.
- Differences to standard SQL
- 4.5.3.17.4.
- UNION
- 4.5.3.17.5.
- INTERSECT
- 4.5.3.17.6.
- EXCEPT
- 4.5.3.18.
- Lexical and logical SELECT clause order
- 4.5.4.
- The INSERT statement
- 4.5.4.1.
- INSERT .. VALUES
- 4.5.4.2.
- INSERT .. DEFAULT VALUES
- 4.5.4.3.
- INSERT .. SET
- 4.5.4.4.
- INSERT .. SELECT
- 4.5.4.5.
- INSERT .. ON DUPLICATE KEY UPDATE
- 4.5.4.6.
- INSERT .. ON DUPLICATE KEY IGNORE
- 4.5.4.7.
- INSERT .. ON CONFLICT .. EXCLUDED (new)
- 4.5.4.8.
- INSERT .. ON CONFLICT
- 4.5.4.9.
- INSERT .. RETURNING
- 4.5.5.
- The UPDATE statement
- 4.5.5.1.
- UPDATE .. SET
- 4.5.5.2.
- UPDATE .. SET ROWS
- 4.5.5.3.
- UPDATE .. FROM
- 4.5.5.4.
- UPDATE .. WHERE
- 4.5.5.5.
- UPDATE .. ORDER BY .. LIMIT
- 4.5.5.6.
- UPDATE .. RETURNING
- 4.5.6.
- The DELETE statement
- 4.5.6.1.
- DELETE .. USING
- 4.5.6.2.
- DELETE .. WHERE
- 4.5.6.3.
- DELETE .. ORDER BY .. LIMIT
- 4.5.6.4.
- DELETE .. RETURNING
- 4.5.7.
- The MERGE statement
- 4.6.
- SQL Statements (DDL)
- 4.6.1.
- The ALTER statement
- 4.6.1.1.
- ALTER DATABASE
- 4.6.1.2.
- ALTER DOMAIN
- 4.6.1.3.
- ALTER INDEX
- 4.6.1.4.
- ALTER SCHEMA
- 4.6.1.5.
- ALTER SEQUENCE
- 4.6.1.6.
- ALTER TABLE
- 4.6.1.7.
- ALTER TYPE
- 4.6.1.7.1.
- ALTER TYPE .. RENAME
- 4.6.1.7.2.
- ALTER TYPE .. for enum alterations
- 4.6.1.8.
- ALTER VIEW
- 4.6.1.8.1.
- ALTER VIEW .. COMMENT
- 4.6.1.8.2.
- ALTER VIEW .. RENAME
- 4.6.1.8.3.
- ALTER VIEW IF EXISTS
- 4.6.2.
- The COMMENT statement
- 4.6.2.1.
- COMMENT ON TABLE
- 4.6.2.2.
- COMMENT ON VIEW
- 4.6.2.3.
- COMMENT ON COLUMN
- 4.6.3.
- The CREATE statement
- 4.6.3.1.
- CREATE DATABASE
- 4.6.3.2.
- CREATE DOMAIN
- 4.6.3.3.
- CREATE FUNCTION
- 4.6.3.3.1.
- Scalar functions
- 4.6.3.3.2.
- CREATE OR REPLACE FUNCTION
- 4.6.3.3.3.
- SQL data access characteristics
- 4.6.3.3.4.
- DETERMINISTIC characteristic
- 4.6.3.3.5.
- ON NULL INPUT characteristic
- 4.6.3.4.
- CREATE INDEX
- 4.6.3.5.
- CREATE PROCEDURE
- 4.6.3.5.1.
- CREATE OR REPLACE PROCEDURE
- 4.6.3.5.2.
- SQL data access characteristics
- 4.6.3.6.
- CREATE SCHEMA
- 4.6.3.7.
- CREATE SEQUENCE
- 4.6.3.8.
- CREATE TABLE
- 4.6.3.8.1.
- Columns
- 4.6.3.8.2.
- Nullability
- 4.6.3.8.3.
- Defaults
- 4.6.3.8.4.
- Identities
- 4.6.3.8.5.
- Computed columns
- 4.6.3.8.6.
- Primary key
- 4.6.3.8.7.
- Unique constraints
- 4.6.3.8.8.
- Foreign keys
- 4.6.3.8.9.
- Check constraints
- 4.6.3.8.10.
- From a SELECT
- 4.6.3.8.11.
- Temporary tables
- 4.6.3.9.
- CREATE TRIGGER
- 4.6.3.9.1.
- Events
- 4.6.3.9.2.
- REFERENCING clause
- 4.6.3.9.3.
- STATEMENT vs ROW triggers
- 4.6.3.9.4.
- WHEN clause
- 4.6.3.10.
- CREATE TYPE
- 4.6.3.11.
- CREATE VIEW
- 4.6.3.11.1.
- OR REPLACE
- 4.6.3.11.2.
- WITH CHECK OPTION
- 4.6.3.11.3.
- WITH READ ONLY
- 4.6.4.
- The DROP statement
- 4.6.4.1.
- DROP DATABASE
- 4.6.4.1.1.
- IF EXISTS
- 4.6.4.2.
- DROP DOMAIN
- 4.6.4.2.1.
- IF EXISTS
- 4.6.4.3.
- DROP FUNCTION
- 4.6.4.3.1.
- IF EXISTS
- 4.6.4.4.
- DROP INDEX
- 4.6.4.4.1.
- IF EXISTS
- 4.6.4.5.
- DROP PROCEDURE
- 4.6.4.5.1.
- IF EXISTS
- 4.6.4.6.
- DROP SCHEMA
- 4.6.4.6.1.
- IF EXISTS
- 4.6.4.7.
- DROP SEQUENCE
- 4.6.4.7.1.
- IF EXISTS
- 4.6.4.8.
- DROP TABLE
- 4.6.4.8.1.
- IF EXISTS
- 4.6.4.9.
- DROP TRIGGER
- 4.6.4.9.1.
- IF EXISTS
- 4.6.4.10.
- DROP TYPE
- 4.6.4.10.1.
- IF EXISTS
- 4.6.4.11.
- DROP VIEW
- 4.6.4.11.1.
- IF EXISTS
- 4.6.5.
- The GRANT statement
- 4.6.6.
- The REVOKE statement
- 4.6.7.
- The SET statement
- 4.6.7.1.
- SET CATALOG
- 4.6.7.2.
- SET SCHEMA
- 4.6.8.
- The TRUNCATE statement
- 4.6.9.
- Generating DDL from objects
- 4.7.
- Procedural statements
- 4.7.1.
- Block statement
- 4.7.2.
- CALL statement
- 4.7.3.
- CONTINUE statement
- 4.7.4.
- EXECUTE statement
- 4.7.5.
- EXIT statement
- 4.7.6.
- FOR statement
- 4.7.7.
- GOTO statement
- 4.7.8.
- IF statement
- 4.7.9.
- Labels
- 4.7.10.
- LOOP statement
- 4.7.11.
- REPEAT statement
- 4.7.12.
- SIGNAL
- 4.7.13.
- Variables
- 4.7.14.
- WHILE statement
- 4.8.
- Catalog and schema expressions
- 4.9.
- Table expressions
- 4.9.1.
- Generated Tables
- 4.9.2.
- Aliased Tables
- 4.9.2.1.
- Aliased generated tables
- 4.9.2.2.
- Aliased table expressions
- 4.9.2.3.
- Derived column lists
- 4.9.2.4.
- Unnamed derived tables
- 4.9.3.
- Joined tables
- 4.9.3.1.
- CROSS JOIN
- 4.9.3.2.
- INNER JOIN
- 4.9.3.3.
- OUTER JOIN
- 4.9.3.4.
- SEMI JOIN
- 4.9.3.5.
- ANTI JOIN
- 4.9.3.6.
- ON clause
- 4.9.3.7.
- ON KEY clause
- 4.9.3.8.
- USING clause
- 4.9.3.9.
- NATURAL clause
- 4.9.3.10.
- LATERAL
- 4.9.3.11.
- APPLY
- 4.9.3.12.
- PARTITION BY
- 4.9.4.
- The VALUES() table constructor
- 4.9.5.
- Derived tables
- 4.9.6.
- Inline derived tables
- 4.9.7.
- The Oracle 11g PIVOT clause
- 4.9.8.
- jOOQ's relational division syntax
- 4.9.9.
- Array and cursor unnesting
- 4.9.10.
- Table-valued functions
- 4.9.11.
- GENERATE_SERIES
- 4.9.12.
- JSON_TABLE
- 4.9.13.
- XMLTABLE
- 4.9.14.
- The DUAL table
- 4.9.15.
- Temporal tables
- 4.9.16.
- Data change delta tables
- 4.10.
- Column expressions
- 4.10.1.
- Table columns
- 4.10.1.1.
- Generated table columns
- 4.10.1.2.
- Dereferenced table columns
- 4.10.1.3.
- Named table columns
- 4.10.2.
- Aliased columns
- 4.10.3.
- Cast expressions
- 4.10.4.
- Datatype coercions
- 4.10.5.
- Readonly columns
- 4.10.6.
- Computed columns
- 4.10.7.
- Collations
- 4.10.8.
- Arithmetic expressions
- 4.10.9.
- String concatenation
- 4.10.10.
- Case sensitivity with strings
- 4.10.11.
- General functions
- 4.10.11.1.
- CHOOSE
- 4.10.11.2.
- COALESCE
- 4.10.11.3.
- DECODE
- 4.10.11.4.
- IIF
- 4.10.11.5.
- NULLIF
- 4.10.11.6.
- NVL
- 4.10.11.7.
- NVL2
- 4.10.12.
- Numeric functions
- 4.10.12.1.
- ABS
- 4.10.12.2.
- ACOS
- 4.10.12.3.
- ASIN
- 4.10.12.4.
- ATAN
- 4.10.12.5.
- ATAN2
- 4.10.12.6.
- CEIL
- 4.10.12.7.
- COS
- 4.10.12.8.
- COSH
- 4.10.12.9.
- COT
- 4.10.12.10.
- COTH
- 4.10.12.11.
- DEG
- 4.10.12.12.
- E
- 4.10.12.13.
- EXP
- 4.10.12.14.
- FLOOR
- 4.10.12.15.
- GREATEST
- 4.10.12.16.
- LEAST
- 4.10.12.17.
- LN
- 4.10.12.18.
- LOG
- 4.10.12.19.
- LOG10
- 4.10.12.20.
- NEG
- 4.10.12.21.
- PI
- 4.10.12.22.
- POWER
- 4.10.12.23.
- RAD
- 4.10.12.24.
- RAND
- 4.10.12.25.
- ROUND
- 4.10.12.26.
- SIGN
- 4.10.12.27.
- SIN
- 4.10.12.28.
- SINH
- 4.10.12.29.
- SQRT
- 4.10.12.30.
- SQUARE
- 4.10.12.31.
- TAN
- 4.10.12.32.
- TANH
- 4.10.12.33.
- TRUNC
- 4.10.12.34.
- WIDTH_BUCKET
- 4.10.13.
- Bitwise functions
- 4.10.13.1.
- BIT_AND
- 4.10.13.2.
- BIT_COUNT
- 4.10.13.3.
- BIT_NAND
- 4.10.13.4.
- BIT_NOR
- 4.10.13.5.
- BIT_NOT
- 4.10.13.6.
- BIT_OR
- 4.10.13.7.
- BIT_XNOR
- 4.10.13.8.
- BIT_XOR
- 4.10.13.9.
- SHL
- 4.10.13.10.
- SHR
- 4.10.14.
- String functions
- 4.10.14.1.
- ASCII
- 4.10.14.2.
- CHR
- 4.10.14.3.
- CONCAT
- 4.10.14.4.
- DIGITS
- 4.10.14.5.
- LEFT
- 4.10.14.6.
- LENGTH
- 4.10.14.7.
- LOWER
- 4.10.14.8.
- LPAD
- 4.10.14.9.
- LTRIM
- 4.10.14.10.
- MD5
- 4.10.14.11.
- MID
- 4.10.14.12.
- OVERLAY
- 4.10.14.13.
- POSITION
- 4.10.14.14.
- REGEXP_REPLACE
- 4.10.14.15.
- REPEAT
- 4.10.14.16.
- REPLACE
- 4.10.14.17.
- REVERSE
- 4.10.14.18.
- RIGHT
- 4.10.14.19.
- RPAD
- 4.10.14.20.
- RTRIM
- 4.10.14.21.
- SPACE
- 4.10.14.22.
- SPLIT_PART
- 4.10.14.23.
- SUBSTRING
- 4.10.14.24.
- SUBSTRING_INDEX
- 4.10.14.25.
- TO_CHAR
- 4.10.14.26.
- TO_HEX
- 4.10.14.27.
- TRANSLATE
- 4.10.14.28.
- TRIM
- 4.10.14.29.
- UPPER
- 4.10.14.30.
- UUID
- 4.10.15.
- Datetime functions
- 4.10.15.1.
- CENTURY
- 4.10.15.2.
- CURRENT_DATE
- 4.10.15.3.
- CURRENT_LOCALDATE
- 4.10.15.4.
- CURRENT_LOCALDATETIME
- 4.10.15.5.
- CURRENT_LOCALTIME
- 4.10.15.6.
- CURRENT_OFFSETDATETIME
- 4.10.15.7.
- CURRENT_OFFSETTIME
- 4.10.15.8.
- CURRENT_TIME
- 4.10.15.9.
- CURRENT_TIMESTAMP
- 4.10.15.10.
- DATE
- 4.10.15.11.
- DATEADD
- 4.10.15.12.
- DATEDIFF
- 4.10.15.13.
- DATESUB
- 4.10.15.14.
- DAY
- 4.10.15.15.
- DAY_OF_YEAR
- 4.10.15.16.
- DECADE
- 4.10.15.17.
- EPOCH
- 4.10.15.18.
- EXTRACT
- 4.10.15.19.
- HOUR
- 4.10.15.20.
- ISO_DAY_OF_WEEK
- 4.10.15.21.
- LOCALDATE
- 4.10.15.22.
- LOCALDATEADD
- 4.10.15.23.
- LOCALDATESUB
- 4.10.15.24.
- LOCALDATETIME
- 4.10.15.25.
- LOCALDATETIMEADD
- 4.10.15.26.
- LOCALDATETIMESUB
- 4.10.15.27.
- LOCALTIME
- 4.10.15.28.
- MILLENNIUM
- 4.10.15.29.
- MINUTE
- 4.10.15.30.
- MONTH
- 4.10.15.31.
- QUARTER
- 4.10.15.32.
- SECOND
- 4.10.15.33.
- TIME
- 4.10.15.34.
- TIMESTAMP
- 4.10.15.35.
- TIMESTAMPADD
- 4.10.15.36.
- TIMESTAMPSUB
- 4.10.15.37.
- TO_DATE
- 4.10.15.38.
- TO_LOCALDATE
- 4.10.15.39.
- TO_LOCALDATETIME
- 4.10.15.40.
- TO_TIMESTAMP
- 4.10.15.41.
- TRUNC
- 4.10.15.42.
- YEAR
- 4.10.16.
- ARRAY functions
- 4.10.16.1.
- ARRAY_GET
- 4.10.16.2.
- ARRAY constructor
- 4.10.16.3.
- ARRAY constructor from subquery
- 4.10.16.4.
- CARDINALITY
- 4.10.17.
- JSON functions
- 4.10.17.1.
- JSON_ARRAY
- 4.10.17.2.
- JSON_OBJECT
- 4.10.17.3.
- JSON_VALUE
- 4.10.18.
- XML functions
- 4.10.18.1.
- XMLATTRIBUTES
- 4.10.18.2.
- XMLCOMMENT
- 4.10.18.3.
- XMLCONCAT
- 4.10.18.4.
- XMLDOCUMENT
- 4.10.18.5.
- XMLELEMENT
- 4.10.18.6.
- XMLFOREST
- 4.10.18.7.
- XMLPARSE
- 4.10.18.8.
- XMLPI
- 4.10.18.9.
- XMLQUERY
- 4.10.18.10.
- XMLSERIALIZE
- 4.10.19.
- System functions
- 4.10.19.1.
- CURRENT_SCHEMA
- 4.10.19.2.
- CURRENT_USER
- 4.10.20.
- Spatial functions
- 4.10.20.1.
- ST_Area
- 4.10.20.2.
- ST_AsText
- 4.10.20.3.
- ST_Centroid
- 4.10.20.4.
- ST_Difference
- 4.10.20.5.
- ST_Distance
- 4.10.20.6.
- ST_EndPoint
- 4.10.20.7.
- ST_ExteriorRing
- 4.10.20.8.
- ST_GeometryN
- 4.10.20.9.
- ST_GeometryType
- 4.10.20.10.
- ST_GeomFromText
- 4.10.20.11.
- ST_InteriorRingN
- 4.10.20.12.
- ST_Intersection
- 4.10.20.13.
- ST_Length
- 4.10.20.14.
- ST_NumGeometries
- 4.10.20.15.
- ST_NumInteriorRings
- 4.10.20.16.
- ST_NumPoints
- 4.10.20.17.
- ST_PointN
- 4.10.20.18.
- ST_SRID
- 4.10.20.19.
- ST_StartPoint
- 4.10.20.20.
- ST_Union
- 4.10.20.21.
- ST_X
- 4.10.20.22.
- ST_Y
- 4.10.20.23.
- ST_Z
- 4.10.21.
- Aggregate functions
- 4.10.21.1.
- Grouping
- 4.10.21.2.
- Distinctness
- 4.10.21.3.
- Filtering
- 4.10.21.4.
- Ordering
- 4.10.21.5.
- Ordering WITHIN GROUP
- 4.10.21.6.
- Keeping
- 4.10.21.7.
- ANY_VALUE
- 4.10.21.8.
- ARRAY_AGG
- 4.10.21.9.
- AVG
- 4.10.21.10.
- BIT_AND_AGG
- 4.10.21.11.
- BIT_NAND_AGG (new)
- 4.10.21.12.
- BIT_NOR_AGG (new)
- 4.10.21.13.
- BIT_OR_AGG
- 4.10.21.14.
- BIT_XOR_AGG
- 4.10.21.15.
- BIT_XNOR_AGG (new)
- 4.10.21.16.
- BOOL_AND
- 4.10.21.17.
- BOOL_OR
- 4.10.21.18.
- COLLECT
- 4.10.21.19.
- COUNT
- 4.10.21.20.
- CUME_DIST
- 4.10.21.21.
- DENSE_RANK
- 4.10.21.22.
- EVERY
- 4.10.21.23.
- GROUP_CONCAT
- 4.10.21.24.
- JSON_ARRAYAGG
- 4.10.21.25.
- JSON_OBJECTAGG
- 4.10.21.26.
- LISTAGG
- 4.10.21.27.
- MAX
- 4.10.21.28.
- MEDIAN
- 4.10.21.29.
- MIN
- 4.10.21.30.
- MODE
- 4.10.21.31.
- MULTISET_AGG
- 4.10.21.32.
- PERCENT_RANK
- 4.10.21.33.
- PERCENTILE_CONT
- 4.10.21.34.
- PERCENTILE_DISC
- 4.10.21.35.
- PRODUCT
- 4.10.21.36.
- RANK
- 4.10.21.37.
- SUM
- 4.10.21.38.
- XMLAGG
- 4.10.22.
- Window functions
- 4.10.22.1.
- PARTITION BY
- 4.10.22.2.
- ORDER BY
- 4.10.22.3.
- ROWS, RANGE, GROUPS (frame clause)
- 4.10.22.4.
- EXCLUDE
- 4.10.22.5.
- NULL treatment
- 4.10.22.6.
- FROM FIRST, FROM LAST
- 4.10.22.7.
- Nested aggregate functions
- 4.10.22.8.
- Window aggregation
- 4.10.22.9.
- Window ordered aggregate
- 4.10.22.10.
- ROW_NUMBER
- 4.10.22.11.
- RANK
- 4.10.22.12.
- DENSE_RANK
- 4.10.22.13.
- PERCENT_RANK
- 4.10.22.14.
- CUME_DIST
- 4.10.22.15.
- NTILE
- 4.10.22.16.
- LEAD
- 4.10.22.17.
- LAG
- 4.10.22.18.
- FIRST_VALUE
- 4.10.22.19.
- LAST_VALUE
- 4.10.22.20.
- NTH_VALUE
- 4.10.23.
- Grouping functions
- 4.10.24.
- User-defined functions
- 4.10.25.
- User-defined aggregate functions
- 4.10.26.
- The CASE expression
- 4.10.27.
- Sequences and serials
- 4.10.28.
- Scalar subqueries
- 4.10.29.
- ARRAY value constructor
- 4.10.30.
- MULTISET value constructor
- 4.10.31.
- Tuples or row value expressions
- 4.10.32.
- Nested records
- 4.11.
- Conditional expressions
- 4.11.1.
- Condition building
- 4.11.2.
- TRUE and FALSE condition
- 4.11.3.
- BOOLEAN columns
- 4.11.4.
- AND, OR, NOT boolean operators
- 4.11.5.
- Comparison predicate
- 4.11.6.
- Boolean operator precedence
- 4.11.7.
- Comparison predicate (degree > 1)
- 4.11.8.
- Quantified comparison predicate
- 4.11.9.
- BETWEEN predicate
- 4.11.10.
- BETWEEN predicate (degree > 1)
- 4.11.11.
- DISTINCT predicate
- 4.11.12.
- DOCUMENT predicate
- 4.11.13.
- EXISTS predicate
- 4.11.14.
- IN predicate
- 4.11.15.
- IN predicate (degree > 1)
- 4.11.16.
- JSON predicate
- 4.11.17.
- JSON_EXISTS predicate
- 4.11.18.
- LIKE predicate
- 4.11.19.
- NULL predicate
- 4.11.20.
- NULL predicate (degree > 1)
- 4.11.21.
- OVERLAPS predicate
- 4.11.22.
- SIMILAR TO predicate
- 4.11.23.
- Spatial predicates
- 4.11.23.1.
- ST_Contains
- 4.11.23.2.
- ST_Crosses
- 4.11.23.3.
- ST_Disjoint
- 4.11.23.4.
- ST_Equals
- 4.11.23.5.
- ST_Intersects
- 4.11.23.6.
- ST_IsClosed
- 4.11.23.7.
- ST_IsEmpty
- 4.11.23.8.
- ST_Overlaps
- 4.11.23.9.
- ST_Touches
- 4.11.23.10.
- ST_Within
- 4.11.24.
- UNIQUE predicate
- 4.11.25.
- XMLEXISTS predicate
- 4.11.26.
- Query By Example (QBE)
- 4.12.
- Operator precedence
- 4.13.
- Synthetic SQL clauses
- 4.14.
- Dynamic SQL
- 4.14.1.
- Optional column expressions (new)
- 4.14.2.
- Optional conditional expressions
- 4.15.
- Plain SQL
- 4.16.
- Plain SQL Templating Language
- 4.17.
- Hints
- 4.17.1.
- MySQL hints
- 4.17.1.1.
- Index hints
- 4.17.1.2.
- STRAIGHT_JOIN
- 4.17.1.3.
- Oracle style hints in MySQL
- 4.17.2.
- Oracle hints
- 4.17.3.
- SQL Server hints
- 4.17.3.1.
- WITH
- 4.17.3.2.
- OPTION
- 4.18.
- SQL Parser
- 4.18.1.
- SQL Parser API
- 4.18.2.
- SQL Parser CLI
- 4.18.3.
- SQL Parser Listener
- 4.18.4.
- SQL translator
- 4.18.5.
- SQL Parser Grammar
- 4.19.
- SQL interpreter
- 4.20.
- Schema diff
- 4.21.
- Schema diff CLI
- 4.22.
- Names and identifiers
- 4.23.
- Bind values and parameters
- 4.23.1.
- Indexed parameters
- 4.23.2.
- Named parameters
- 4.23.3.
- Inlined parameters
- 4.23.4.
- SQL injection
- 4.24.
- QueryParts
- 4.24.1.
- SQL rendering
- 4.24.2.
- Declaration vs reference
- 4.24.3.
- Pretty printing SQL
- 4.24.4.
- Variable binding
- 4.24.5.
- Custom data type bindings
- 4.24.6.
- Custom syntax elements
- 4.24.7.
- Plain SQL QueryParts
- 4.24.8.
- Serializability
- 4.24.9.
- SQL transformation
- 4.24.9.1.
- ANSI JOIN to table lists
- 4.24.9.2.
- Table lists to ANSI JOIN
- 4.24.9.3.
- ROWNUM to LIMIT
- 4.24.9.4.
- QUALIFY to derived table
- 4.24.9.5.
- IN condition subquery with LIMIT to derived table
- 4.24.9.6.
- Unnecessary arithmetic expressions
- 4.24.9.7.
- Pattern based transformation (new)
- 4.24.9.7.1.
- AND to NOT IN (new)
- 4.24.9.7.2.
- Arithmetic expressions (new)
- 4.24.9.7.3.
- COUNT(*) scalar subquery comparison (new)
- 4.24.9.7.4.
- COUNT(expr) scalar subquery comparison (new)
- 4.24.9.7.5.
- Empty scalar subquery (new)
- 4.24.9.7.6.
- Hyperbolic functions (new)
- 4.24.9.7.7.
- Idempotent function repetition (new)
- 4.24.9.7.8.
- Inverse hyperbolic functions (new)
- 4.24.9.7.9.
- Logarithmic functions (new)
- 4.24.9.7.10.
- Merge AND predicates (new)
- 4.24.9.7.11.
- Merge BIT_NOT with BIT_NAND (new)
- 4.24.9.7.12.
- Merge BIT_NOT with BIT_NOR (new)
- 4.24.9.7.13.
- Merge BIT_NOT with BIT_XNOR (new)
- 4.24.9.7.14.
- Merge IN predicates (new)
- 4.24.9.7.15.
- Merge NOT with comparison predicates (new)
- 4.24.9.7.16.
- Merge NOT with DISTINCT predicate (new)
- 4.24.9.7.17.
- Merge OR predicates (new)
- 4.24.9.7.18.
- Merge range predicates (new)
- 4.24.9.7.19.
- Normalise associative operations (new)
- 4.24.9.7.20.
- Normalise fields compared to values (new)
- 4.24.9.7.21.
- Normalise IN list with single element to comparison (new)
- 4.24.9.7.22.
- OR to IN (new)
- 4.24.9.7.23.
- Repeated bitwise negation (new)
- 4.24.9.7.24.
- Repeated logical negation (new)
- 4.24.9.7.25.
- Repeated NOT (new)
- 4.24.9.7.26.
- Trigonometric functions (new)
- 4.24.9.7.27.
- Trim (new)
- 4.24.9.7.28.
- Trivial case abbreviations (new)
- 4.24.9.7.29.
- Trivial predicates (new)
- 4.24.10.
- Custom SQL transformation with VisitListener
- 4.24.10.1.
- Example: Logging abbreviated bind values
- 4.25.
- Zero-based vs one-based APIs
- 4.26.
- SQL building in Kotlin
- 4.26.1.
- Kotlin MULTISET Collectors (new)
- 4.26.2.
- Kotlin BOOLEAN value expressions
- 4.26.3.
- Kotlin ARRAY access
- 4.26.4.
- Kotlin coroutine support (new)
- 4.27.
- 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.
- Ad-hoc Converter
- 5.3.9.
- ConverterProvider
- 5.3.10.
- Lazy fetching
- 5.3.11.
- Lazy fetching with Streams
- 5.3.12.
- Many fetching
- 5.3.13.
- Later fetching
- 5.3.14.
- Reactive Fetching
- 5.3.15.
- ResultSet fetching
- 5.3.16.
- Auto data type conversion
- 5.3.17.
- Custom data type conversion
- 5.4.
- Static statements vs. Prepared Statements
- 5.5.
- Reusing a Query's PreparedStatement
- 5.6.
- JDBC flags
- 5.7.
- Using JDBC batch operations
- 5.8.
- Sequence execution
- 5.9.
- Stored procedures and functions
- 5.9.1.
- Oracle Packages
- 5.9.2.
- Oracle member procedures
- 5.10.
- Exporting to XML, CSV, JSON, HTML, Text, Charts
- 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.10.6.
- Exporting Charts
- 5.10.7.
- FormattingProvider
- 5.11.
- Importing data
- 5.11.1.
- The Loader API
- 5.11.2.
- Import options
- 5.11.2.1.
- Throttling
- 5.11.2.2.
- Duplicate handling
- 5.11.2.3.
- Error handling
- 5.11.3.
- Import data sources
- 5.11.3.1.
- Importing CSV
- 5.11.3.2.
- Importing JSON
- 5.11.3.3.
- Importing records
- 5.11.3.4.
- Importing arrays
- 5.11.3.5.
- Importing XML
- 5.11.4.
- Import listeners
- 5.11.5.
- Import result and error handling
- 5.12.
- CRUD with UpdatableRecords
- 5.12.1.
- Simple CRUD
- 5.12.2.
- Records' internal flags
- 5.12.3.
- IDENTITY values
- 5.12.4.
- Navigation methods
- 5.12.5.
- Non-updatable records
- 5.12.6.
- Optimistic locking
- 5.12.7.
- Batch execution
- 5.12.8.
- CRUD SPI: RecordListener
- 5.13.
- DAOs
- 5.14.
- Transaction management
- 5.15.
- Exception handling
- 5.16.
- ExecuteListeners
- 5.17.
- Database meta data
- 5.17.1.
- JDBC meta data
- 5.17.2.
- Interpreted meta data
- 5.17.3.
- XML meta data
- 5.17.4.
- Generated meta data
- 5.18.
- JDBC Connection
- 5.19.
- Batched Connection
- 5.20.
- Mocking Connection
- 5.21.
- Mock File Database
- 5.22.
- Parsing Connection
- 5.23.
- Diagnostics
- 5.23.1.
- Too Many Rows
- 5.23.2.
- Too Many Columns
- 5.23.3.
- Duplicate Statements
- 5.23.4.
- Repeated statements
- 5.23.5.
- WasNull calls
- 5.23.6.
- Trivial condition (new)
- 5.24.
- Logging with LoggerListener
- 5.25.
- Logging Connection
- 5.26.
- Performance considerations
- 5.27.
- Alternative execution models
- 5.27.1.
- Using jOOQ with Spring's JdbcTemplate
- 5.27.2.
- Using jOOQ with JPA
- 5.27.2.1.
- Using jOOQ with JPA Native Query
- 5.27.2.2.
- Using jOOQ with JPA entities
- 5.27.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.
- Error handling
- 6.2.3.
- Jdbc
- 6.2.4.
- Generator
- 6.2.5.
- Database
- 6.2.5.1.
- Database name and properties
- 6.2.5.2.
- RegexFlags
- 6.2.5.3.
- Includes and Excludes
- 6.2.5.4.
- Include object types
- 6.2.5.5.
- Record Version and Timestamp Fields
- 6.2.5.6.
- Comments
- 6.2.5.7.
- Synthetic objects
- 6.2.5.7.1.
- Synthetic columns (new)
- 6.2.5.7.2.
- Synthetic readonly columns
- 6.2.5.7.3.
- Synthetic readonly ROWIDs
- 6.2.5.7.4.
- Synthetic identities
- 6.2.5.7.5.
- Synthetic primary keys
- 6.2.5.7.6.
- Synthetic unique keys
- 6.2.5.7.7.
- Synthetic foreign keys
- 6.2.5.8.
- Date as timestamp
- 6.2.5.9.
- Ignore procedure return values (deprecated)
- 6.2.5.10.
- Readonly columns
- 6.2.5.11.
- Unsigned types
- 6.2.5.12.
- Catalog and schema mapping
- 6.2.5.13.
- Catalog and schema version providers
- 6.2.5.14.
- Custom ordering of generated code
- 6.2.5.15.
- Forced types
- 6.2.5.15.1.
- Matching of forced types
- 6.2.5.15.2.
- Data type rewriting
- 6.2.5.15.3.
- Qualified converters
- 6.2.5.15.4.
- Inline converters
- 6.2.5.15.5.
- Lambda converters
- 6.2.5.15.6.
- Enum converters
- 6.2.5.15.7.
- Jackson converters (new)
- 6.2.5.15.8.
- JAXB converters (new)
- 6.2.5.15.9.
- Data type bindings
- 6.2.5.15.10.
- Client side computed columns (new)
- 6.2.5.15.11.
- Audit columns (new)
- 6.2.5.15.12.
- Visibility Modifier (per forced type) (new)
- 6.2.5.16.
- Table valued functions
- 6.2.6.
- Generate
- 6.2.6.1.
- Annotations
- 6.2.6.2.
- Covariant overrides
- 6.2.6.2.1.
- Overriding as()
- 6.2.6.2.2.
- Overriding rename()
- 6.2.6.3.
- Default catalog and schema
- 6.2.6.4.
- Extended types
- 6.2.6.5.
- Fluent setters
- 6.2.6.6.
- Fully Qualified Types
- 6.2.6.7.
- Global Artefacts
- 6.2.6.8.
- Implicit JOIN paths
- 6.2.6.9.
- Java Time Types
- 6.2.6.10.
- Serial Version UID
- 6.2.6.11.
- Sources
- 6.2.6.12.
- Text blocks (new)
- 6.2.6.13.
- Visibility Modifier (global)
- 6.2.6.14.
- Whitespace (newlines and indentation)
- 6.2.6.15.
- Zero Scale Decimal Types
- 6.2.7.
- Output target configuration
- 6.3.
- Programmatic generator configuration
- 6.4.
- Custom generator strategies
- 6.5.
- Matcher strategies
- 6.5.1.
- MatcherRule
- 6.5.2.
- Matching catalogs
- 6.5.3.
- Matching schemas
- 6.5.4.
- Matching tables
- 6.5.5.
- Matching fields
- 6.5.6.
- Matching routines
- 6.5.7.
- Matching sequences
- 6.5.8.
- Matching enums
- 6.5.9.
- Matching embeddables
- 6.5.10.
- Matcher examples
- 6.6.
- Custom code sections
- 6.7.
- Generated global artefacts
- 6.8.
- Generated tables
- 6.9.
- Generated records
- 6.10.
- Generated POJOs
- 6.11.
- Generated Interfaces
- 6.12.
- Generated DAOs
- 6.13.
- Generated sequences
- 6.14.
- Generated procedures
- 6.15.
- Generated domains
- 6.16.
- Generated UDTs
- 6.17.
- Data type extensions
- 6.17.1.
- PostgreSQL
- 6.18.
- Embeddable types
- 6.18.1.
- Configuration
- 6.18.2.
- Overlapping embeddable types
- 6.18.3.
- Field replacement
- 6.18.4.
- Embedded keys
- 6.18.5.
- Embedded domains
- 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.
- LiquibaseDatabase: Code generation from Liquibase XML, YAML, JSON files
- 6.26.
- XMLGenerator: Generating XML
- 6.27.
- KotlinGenerator
- 6.28.
- ScalaGenerator
- 6.29.
- Running the code generator with Maven
- 6.30.
- Running the code generator with Ant
- 6.31.
- Running the code generator with Gradle
- 6.32.
- System properties governing code generation
- 6.33.
- Features requiring generated code
- 7.
- Tools
- 7.1.
- API validation using the Checker Framework or Error Prone
- 7.2.
- jOOQ Refaster
- 7.3.
- jOOQ Console
- 8.
- Coming from JPA
- 8.1.
- Set based thinking
- 8.2.
- Database first
- 8.3.
- Eager or lazy loading
- 8.4.
- First level cache and second level cache
- 8.5.
- Embeddable
- 8.6.
- AttributeConverter
- 8.7.
- User types
- 8.8.
- Implicit JOIN
- 8.9.
- @OneToOne or @ManyToOne
- 8.10.
- @OneToMany or @ManyToMany
- 9.
- Reference
- 9.1.
- Supported RDBMS
- 9.2.
- Commercial only features
- 9.3.
- Experimental features
- 9.4.
- Data types
- 9.4.1.
- BLOBs and CLOBs
- 9.4.2.
- BOOLEAN data type
- 9.4.3.
- Unsigned integer types
- 9.4.4.
- INTERVAL data types
- 9.4.5.
- JSON data types
- 9.4.6.
- XML data types
- 9.4.7.
- Spatial data types
- 9.4.8.
- CURSOR data types
- 9.4.9.
- ARRAY and TABLE data types
- 9.4.10.
- Oracle DATE data type
- 9.4.11.
- Domains
- 9.5.
- SQL to DSL mapping rules
- 9.6.
- Quality Assurance
- 9.7.
- Security
- 9.7.1.
- SQL Injection
- 9.7.2.
- Debug logging
- 9.7.3.
- Exception message
- 9.7.4.
- Contact
- 9.8.
- Migrating to jOOQ 3.0
- 9.9.
- Don't do this
- 9.9.1.
- jOOQ: Implementing the DSL types
- 9.9.2.
- jOOQ: Referencing the Step types
- 9.9.3.
- Schema: NULL columns
- 9.9.4.
- Schema: Unnamed constraints
- 9.9.5.
- Schema: Unnecessary surrogate keys
- 9.9.6.
- Schema: Wrong data types
- 9.9.7.
- SQL: COUNT(*) instead of EXISTS()
- 9.9.8.
- SQL: N+1
- 9.9.9.
- SQL: NOT IN predicate
- 9.9.10.
- SQL: Rely on implicit ordering
- 9.9.11.
- SQL: SELECT *
- 9.9.12.
- SQL: Unnecessary UNION instead of UNION ALL
- 9.10.
- The most important jOOQ types
- 9.11.
- Credits
1. Preface
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ's reason for being - compared to JPA
Java and SQL have come a long way. SQL is an "old", yet established and well-understood technology. Java is a legacy too, although its platform JVM allows for many new and contemporary languages built on top of it. Yet, after all these years, libraries dealing with the interface between SQL and Java have come and gone, leaving JPA to be a standard that is accepted only with doubts, short of any surviving options.
So far, there had been only few database abstraction frameworks or libraries, that truly respected SQL as a first class citizen among languages. Most frameworks, including the industry standards JPA, EJB, Hibernate, JDO, Criteria Query, and many others try to hide SQL itself, minimising its scope to things called JPQL, HQL, JDOQL and various other inferior query languages
jOOQ has come to fill this gap.
jOOQ's reason for being - compared to LINQ
Other platforms incorporate ideas such as LINQ (with LINQ-to-SQL), or Scala's SLICK, or also Java's QueryDSL to better integrate querying as a concept into their respective language. By querying, they understand querying of arbitrary targets, such as SQL, XML, Collections and other heterogeneous data stores. jOOQ claims that this is going the wrong way too.
In more advanced querying use-cases (more than simple CRUD and the occasional JOIN), people will want to profit from the expressivity of SQL. Due to the relational nature of SQL, this is quite different from what object-oriented and partially functional languages such as C#, Scala, or Java can offer.
It is very hard to formally express and validate joins and the ad-hoc table expression types they create. It gets even harder when you want support for more advanced table expressions, such as pivot tables, unnested cursors, or just arbitrary projections from derived tables. With a very strong object-oriented typing model, these features will probably stay out of scope.
In essence, the decision of creating an API that looks like SQL or one that looks like C#, Scala, Java is a definite decision in favour of one or the other platform. While it will be easier to evolve SLICK in similar ways as LINQ (or QueryDSL in the Java world), SQL feature scope that clearly communicates its underlying intent will be very hard to add, later on (e.g. how would you model Oracle's partitioned outer join syntax? How would you model ANSI/ISO SQL:1999 grouping sets? How can you support scalar subquery caching? etc...).
jOOQ has come to fill this gap.
jOOQ's reason for being - compared to SQL / JDBC
So why not just use SQL?
SQL can be written as plain text and passed through the JDBC API. Over the years, people have become wary of this approach for many reasons:
- No typesafety
- No syntax safety
- No bind value index safety
- Verbose SQL String concatenation
- Boring bind value indexing techniques
- Verbose resource and exception handling in JDBC
- A very "stateful", not very object-oriented JDBC API, which is hard to use
For these many reasons, other frameworks have tried to abstract JDBC away in the past in one way or another. Unfortunately, many have completely abstracted SQL away as well
jOOQ has come to fill this gap.
jOOQ is different
SQL was never meant to be abstracted. To be confined in the narrow boundaries of heavy mappers, hiding the beauty and simplicity of relational data. SQL was never meant to be object-oriented. SQL was never meant to be anything other than... SQL!
2. Copyright, License, and Trademarks
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This section lists the various licenses that apply to different versions of jOOQ. Prior to version 3.2, jOOQ was shipped for free under the terms of the Apache Software License 2.0. With jOOQ 3.2, jOOQ became dual-licensed: Apache Software License 2.0 (for use with Open Source databases) and commercial (for use with commercial databases).
This manual itself (as well as the www.jooq.org public website) is licensed to you under the terms of the CC BY-SA 4.0 license.
Please contact legal@datageekery.com, should you have any questions regarding licensing.
License for jOOQ 3.2 and later
This work is dual-licensed - under the Apache Software License 2.0 (the "ASL") - under the jOOQ License and Maintenance Agreement (the "jOOQ License") ============================================================================= You may choose which license applies to you: - If you're using this work with Open Source databases, you may choose either ASL or jOOQ License. - If you're using this work with at least one commercial database, you must choose jOOQ License For more information, please visit https://www.jooq.org/licenses Apache Software License 2.0: ----------------------------------------------------------------------------- Licensed under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at https://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License. jOOQ License and Maintenance Agreement: ----------------------------------------------------------------------------- Data Geekery grants the Customer the non-exclusive, timely limited and non-transferable license to install and use the Software under the terms of the jOOQ License and Maintenance Agreement. This library is distributed with a LIMITED WARRANTY. See the jOOQ License and Maintenance Agreement for more details: https://www.jooq.org/licensing
Historic license for jOOQ 1.x, 2.x, 3.0, 3.1
Licensed under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at https://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.
Trademarks owned by Data Geekery™ GmbH
- jOOλ™ is a trademark by Data Geekery™ GmbH
- jOOQ™ is a trademark by Data Geekery™ GmbH
- jOOR™ is a trademark by Data Geekery™ GmbH
- jOOU™ is a trademark by Data Geekery™ GmbH
- jOOX™ is a trademark by Data Geekery™ GmbH
Trademarks owned by database vendors with no affiliation to Data Geekery™ GmbH
- Access® is a registered trademark of Microsoft® Inc.
- Adaptive Server® Enterprise is a registered trademark of Sybase®, Inc.
- DB2® is a registered trademark of IBM® Corp.
- Derby is a trademark of the Apache™ Software Foundation
- H2 is a trademark of the H2 Group
- HANA is a trademark of SAP SE
- HSQLDB is a trademark of The hsql Development Group
- Ingres is a trademark of Actian™ Corp.
- MariaDB is a trademark of Monty Program Ab
- MySQL® is a registered trademark of Oracle® Corp.
- Firebird® is a registered trademark of Firebird Foundation Inc.
- Oracle® database is a registered trademark of Oracle® Corp.
- PostgreSQL® is a registered trademark of The PostgreSQL Global Development Group
- Postgres Plus® is a registered trademark of EnterpriseDB® software
- SQL Anywhere® is a registered trademark of Sybase®, Inc.
- SQL Server® is a registered trademark of Microsoft® Inc.
- SQLite is a trademark of Hipp, Wyrick & Company, Inc.
Other trademarks by vendors with no affiliation to Data Geekery™ GmbH
- Java® is a registered trademark by Oracle® Corp. and/or its affiliates
- Liquibase is a trademark by Datical, Inc
- Flyway is a trademark by Red Gate Software Ltd
- Scala is a trademark of EPFL
Other trademark remarks
Other names may be trademarks of their respective owners.
Throughout the manual, the above trademarks are referenced without a formal ® (R) or ™ (TM) symbol. It is believed that referencing third-party trademarks in this manual or on the jOOQ website constitutes "fair use". Please contact us if you think that your trademark(s) are not properly attributed.
Contributions
The following are authors and contributors of jOOQ or parts of jOOQ in alphabetical order:
- Aaron Digulla
- Andreas Franzén
- Anuraag Agrawal
- Arnaud Roger
- Art O Cathain
- Artur Dryomov
- Ben Manes
- Brent Douglas
- Brett Meyer
- Christian Stein
- Christopher Deckers
- Dennis Neufeld
- Ed Schaller
- Eric Peters
- Ernest Mishkin
- Espen Stromsnes
- Eugeny Karpov
- Fabrice Le Roy
- Gonzalo Ortiz Jaureguizar
- Gregory Hlavac
- Henrik Sjöstrand
- Ivan Dugic
- Javier Durante
- Johannes Bühler
- Joseph B Phillips
- Joseph Pachod
- Knut Wannheden
- Laurent Pireyn
- Logan Hauspie
- Luc Marchaud
- Lukas Eder
- Matti Tahvonen
- Michael Doberenz
- Michael Simons
- Michał Kołodziejski
- Miguel Gonzalez Sanchez
- Mustafa Yücel
- Nathaniel Fischer
- Octavia Togami
- Oliver Flege
- Per Lundberg
- Peter Ertl
- Richard Bradley
- Robin Stocker
- Roland Weisleder
- Samy Deghou
- Sander Plas
- Sean Wellington
- Sergey Epik
- Sergey Zhuravlev
- Stanislas Nanchen
- Stephan Schroevers
- Sugiharto Lim
- Sven Jacobs
- Szymon Jachim
- Terence Zhang
- Thomas Darimont
- Timothy Wilson
- Timur Shaidullin
- Tsukasa Kitachi
- Victor Bronstein
- Victor Z. Peng
- Vladimir Kulev
- Vladimir Vinogradov
- Vojtech Polivka
- Wang Gaoyuan
- Wyke Oskar
- Xavier Oliver
- Zoltan Tamasi
See the following website for details about contributing to jOOQ:
https://www.jooq.org/legal/contributions
3. Getting started with jOOQ
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
These chapters contain a quick overview of how to get started with this manual and with jOOQ. While the subsequent chapters contain a lot of reference information, this chapter here just wraps up the essentials.
3.1. How to read this manual
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This section helps you correctly interpret this manual in the context of jOOQ.
Code blocks
The following are code blocks:
-- A SQL code block SELECT 1 FROM DUAL
// A Java code block for (int i = 0; i < 10; i++);
<!-- An XML code block --> <hello what="world"></hello>
# A config file code block org.jooq.property=value
These are useful to provide examples in code. Often, with jOOQ, it is even more useful to compare SQL code with its corresponding Java/jOOQ code. When this is done, the blocks are aligned side-by-side, with SQL usually being on the left, and an equivalent jOOQ DSL query in Java usually being on the right:
-- In SQL: SELECT 1 FROM DUAL
// Using jOOQ: create.selectOne().fetch()
Code block contents
The contents of code blocks follow conventions, too. If nothing else is mentioned next to any given code block, then the following can be assumed:
-- SQL assumptions ------------------ -- If nothing else is specified, assume that the Oracle syntax is used SELECT 1 FROM DUAL
// Java assumptions // ---------------- // Whenever you see "standalone functions", assume they were static imported from org.jooq.impl.DSL // "DSL" is the entry point of the static query DSL exists(); max(); min(); val(); inline(); // correspond to DSL.exists(); DSL.max(); DSL.min(); etc... // Whenever you see BOOK/Book, AUTHOR/Author and similar entities, assume they were (static) imported from the generated schema BOOK.TITLE, AUTHOR.LAST_NAME // com.example.generated.Tables.BOOK.TITLE, com.example.generated.Tables.AUTHOR.LAST_NAME FK_BOOK_AUTHOR // com.example.generated.Keys.FK_BOOK_AUTHOR // Whenever you see "create" being used in Java code, assume that this is an instance of org.jooq.DSLContext. // The reason why it is called "create" is the fact, that a jOOQ QueryPart is being created from the DSL object. // "create" is thus the entry point of the non-static query DSL DSLContext create = DSL.using(connection, SQLDialect.ORACLE);
Your naming may differ, of course. For instance, you could name the "create" instance "db", instead.
Execution
When you're coding PL/SQL, T-SQL or some other procedural SQL language, SQL statements are always executed immediately at the semi-colon. This is not the case in jOOQ, because as an internal DSL, jOOQ can never be sure that your statement is complete until you call fetch()
or execute()
. The manual tries to apply fetch()
and execute()
as thoroughly as possible. If not, it is implied:
SELECT 1 FROM DUAL UPDATE t SET v = 1
create.selectOne().fetch(); create.update(T).set(T.V, 1).execute();
Degree (arity)
jOOQ records (and many other API elements) have a degree N between 1 and 22. The variable degree of an API element is denoted as [N], e.g. Row[N] or Record[N]. The term "degree" is preferred over arity, as "degree" is the term used in the SQL standard, whereas "arity" is used more often in mathematics and relational theory.
Settings
jOOQ allows to override runtime behaviour using org.jooq.conf.Settings
. If nothing is specified, the default runtime settings are assumed.
Sample database
jOOQ query examples run against the sample database. See the manual's section about the sample database used in this manual to learn more about the sample database.
3.2. The sample database used in this manual
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For the examples in this manual, the same database will always be referred to. It essentially consists of these entities created using the Oracle dialect
CREATE TABLE language ( id NUMBER(7) NOT NULL PRIMARY KEY, cd CHAR(2) NOT NULL, description VARCHAR2(50) ); CREATE TABLE author ( id NUMBER(7) NOT NULL PRIMARY KEY, first_name VARCHAR2(50), last_name VARCHAR2(50) NOT NULL, date_of_birth DATE, year_of_birth NUMBER(7), distinguished NUMBER(1) ); CREATE TABLE book ( id NUMBER(7) NOT NULL PRIMARY KEY, author_id NUMBER(7) NOT NULL, title VARCHAR2(400) NOT NULL, published_in NUMBER(7) NOT NULL, language_id NUMBER(7) NOT NULL, CONSTRAINT fk_book_author FOREIGN KEY (author_id) REFERENCES author(id), CONSTRAINT fk_book_language FOREIGN KEY (language_id) REFERENCES language(id) ); CREATE TABLE book_store ( name VARCHAR2(400) NOT NULL UNIQUE ); CREATE TABLE book_to_book_store ( name VARCHAR2(400) NOT NULL, book_id INTEGER NOT NULL, stock INTEGER, PRIMARY KEY(name, book_id), CONSTRAINT fk_b2bs_book_store FOREIGN KEY (name) REFERENCES book_store (name) ON DELETE CASCADE, CONSTRAINT fk_b2bs_book FOREIGN KEY (book_id) REFERENCES book (id) ON DELETE CASCADE );
More entities, types (e.g. UDT's, ARRAY types, ENUM types, etc), stored procedures and packages are introduced for specific examples
In addition to the above, you may assume the following sample data:
INSERT INTO language (id, cd, description) VALUES (1, 'en', 'English'); INSERT INTO language (id, cd, description) VALUES (2, 'de', 'Deutsch'); INSERT INTO language (id, cd, description) VALUES (3, 'fr', 'Français'); INSERT INTO language (id, cd, description) VALUES (4, 'pt', 'Português'); INSERT INTO author (id, first_name, last_name, date_of_birth , year_of_birth) VALUES (1 , 'George' , 'Orwell' , DATE '1903-06-26', 1903 ); INSERT INTO author (id, first_name, last_name, date_of_birth , year_of_birth) VALUES (2 , 'Paulo' , 'Coelho' , DATE '1947-08-24', 1947 ); INSERT INTO book (id, author_id, title , published_in, language_id) VALUES (1 , 1 , '1984' , 1948 , 1 ); INSERT INTO book (id, author_id, title , published_in, language_id) VALUES (2 , 1 , 'Animal Farm' , 1945 , 1 ); INSERT INTO book (id, author_id, title , published_in, language_id) VALUES (3 , 2 , 'O Alquimista', 1988 , 4 ); INSERT INTO book (id, author_id, title , published_in, language_id) VALUES (4 , 2 , 'Brida' , 1990 , 2 ); INSERT INTO book_store VALUES ('Orell Füssli'); INSERT INTO book_store VALUES ('Ex Libris'); INSERT INTO book_store VALUES ('Buchhandlung im Volkshaus'); INSERT INTO book_to_book_store VALUES ('Orell Füssli' , 1, 10); INSERT INTO book_to_book_store VALUES ('Orell Füssli' , 2, 10); INSERT INTO book_to_book_store VALUES ('Orell Füssli' , 3, 10); INSERT INTO book_to_book_store VALUES ('Ex Libris' , 1, 1 ); INSERT INTO book_to_book_store VALUES ('Ex Libris' , 3, 2 ); INSERT INTO book_to_book_store VALUES ('Buchhandlung im Volkshaus', 3, 1 );
3.3. Different use cases for jOOQ
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ has originally been created as a library for complete abstraction of JDBC and all database interaction. Various best practices that are frequently encountered in pre-existing software products are applied to this library. This includes:
- Typesafe database object referencing through generated schema, table, column, record, procedure, type, dao, pojo artefacts (see the chapter about code generation)
- Typesafe SQL construction / SQL building through a complete querying DSL API modelling SQL as a domain specific language in Java (see the chapter about the query DSL API)
- Convenient query execution through an improved API for result fetching (see the chapters about the various types of data fetching)
- SQL dialect abstraction and SQL clause emulation to improve cross-database compatibility and to enable missing features in simpler databases (see the chapter about SQL dialects)
- SQL logging and debugging using jOOQ as an integral part of your development process (see the chapters about logging)
Effectively, jOOQ was originally designed to replace any other database abstraction framework short of the ones handling connection pooling (and more sophisticated transaction management)
Use jOOQ the way you prefer
... but open source is community-driven. And the community has shown various ways of using jOOQ that diverge from its original intent. Some use cases encountered are:
- Using Hibernate for 70% of the queries (i.e. CRUD) and jOOQ for the remaining 30% where SQL is really needed
- Using jOOQ for SQL building and JDBC for SQL execution
- Using jOOQ for SQL building and Spring Data for SQL execution
- Using jOOQ without the source code generator to build the basis of a framework for dynamic SQL execution.
The following sections explain about various use cases for using jOOQ in your application.
3.3.1. jOOQ as a SQL builder without code generation
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
We strongly recommend to use jOOQ with its code generator to get the most out of jOOQ!
However, if you have a dynamic schema, you don't have to use the code generator. This is the most simple of all use cases, allowing for construction of valid SQL for any database. In this use case, you will not use jOOQ's code generator and maybe not even jOOQ's query execution facilities. Instead, you'll use jOOQ's query DSL API to wrap strings, literals and other user-defined objects into an object-oriented, type-safe AST modelling your SQL statements. An example is given here:
// Fetch a SQL string from a jOOQ Query in order to manually execute it with another tool. // For simplicity reasons, we're using the API to construct case-insensitive object references, here. Query query = create.select(field("BOOK.TITLE"), field("AUTHOR.FIRST_NAME"), field("AUTHOR.LAST_NAME")) .from(table("BOOK")) .join(table("AUTHOR")) .on(field("BOOK.AUTHOR_ID").eq(field("AUTHOR.ID"))) .where(field("BOOK.PUBLISHED_IN").eq(1948)); String sql = query.getSQL(); List<Object> bindValues = query.getBindValues();
The SQL string built with the jOOQ query DSL can then be executed using JDBC directly, using Spring's JdbcTemplate, using Apache DbUtils and many other tools (note that since jOOQ uses java.sql.PreparedStatement
by default, this will generate a bind variable for "1948". Read more about bind variables here).
You can also avoid getting the SQL string and bind values separately:
String sql = query.getSQL(ParamType.INLINED);
If you wish to use jOOQ only as a SQL builder, the following sections of the manual will be of interest to you:
- SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
- Plain SQL: This section contains information useful in particular to those that want to supply table expressions, column expressions, etc. as plain SQL to jOOQ, rather than through generated artefacts
- Bind values: This section explains how bind values are managed and/or inlined in jOOQ.
3.3.2. jOOQ as a SQL builder with code generation
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In addition to using jOOQ as a standalone SQL builder, you can also use jOOQ's code generation features in order to compile your SQL statements using a Java compiler against an actual database schema. This adds a lot of power and expressiveness to just simply constructing SQL using the query DSL and custom strings and literals, as you can be sure that all database artefacts actually exist in the database, and that their type is correct. We strongly recommend using this approach. An example is given here:
// Fetch a SQL string from a jOOQ Query in order to manually execute it with another tool. Query query = create.select(BOOK.TITLE, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(BOOK) .join(AUTHOR) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .where(BOOK.PUBLISHED_IN.eq(1948)); String sql = query.getSQL(); List<Object> bindValues = query.getBindValues();
The SQL string built with the jOOQ query DSL can then be executed using JDBC directly, using Spring's JdbcTemplate, using Apache DbUtils and many other tools (note that since jOOQ uses java.sql.PreparedStatement
by default, this will generate a bind variable for "1948". Read more about bind variables here).
You can also avoid getting the SQL string and bind values separately:
String sql = query.getSQL(ParamType.INLINED);
If you wish to use jOOQ only as a SQL builder with code generation, the following sections of the manual will be of interest to you:
- SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
- Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
- Bind values: This section explains how bind values are managed and/or inlined in jOOQ.
3.3.3. jOOQ as a SQL executor
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Instead of any tool mentioned in the previous chapters, you can also use jOOQ directly to execute your jOOQ-generated SQL statements. This will add a lot of convenience on top of the previously discussed API for typesafe SQL construction, when you can re-use the information from generated classes to fetch records and custom data types. An example is given here:
// Typesafely execute the SQL statement directly with jOOQ Result<Record3<String, String, String>> result = create.select(BOOK.TITLE, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(BOOK) .join(AUTHOR) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .where(BOOK.PUBLISHED_IN.eq(1948)) .fetch();
By having jOOQ execute your SQL, the jOOQ query DSL becomes truly embedded SQL.
jOOQ doesn't stop here, though! You can execute any SQL with jOOQ. In other words, you can use any other SQL building tool and run the SQL statements with jOOQ. An example is given here:
// Use your favourite tool to construct SQL strings: String sql = "SELECT title, first_name, last_name FROM book JOIN author ON book.author_id = author.id " + "WHERE book.published_in = 1984"; // Fetch results using jOOQ Result<Record> result = create.fetch(sql); // Or execute that SQL with JDBC, fetching the ResultSet with jOOQ: ResultSet rs = connection.createStatement().executeQuery(sql); Result<Record> result = create.fetch(rs);
If you wish to use jOOQ as a SQL executor with (or without) code generation, the following sections of the manual will be of interest to you:
- SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
- Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
- SQL execution: This section contains a lot of information about executing SQL statements using the jOOQ API
- Fetching: This section contains some useful information about the various ways of fetching data with jOOQ
3.3.4. jOOQ for CRUD
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Apart from jOOQ's fluent API for query construction, jOOQ can also help you execute everyday CRUD operations. An example is given here:
// Fetch an author AuthorRecord author = create.fetchOne(AUTHOR, AUTHOR.ID.eq(1)); // Create a new author, if it doesn't exist yet if (author == null) { author = create.newRecord(AUTHOR); author.setId(1); author.setFirstName("Dan"); author.setLastName("Brown"); } // Mark the author as a "distinguished" author and store it author.setDistinguished(1); // Executes an update on existing authors, or insert on new ones author.store();
If you wish to use all of jOOQ's features, the following sections of the manual will be of interest to you (including all sub-sections):
- SQL building: This section contains a lot of information about creating SQL statements using the jOOQ API
- Code generation: This section contains the necessary information to run jOOQ's code generator against your developer database
- SQL execution: This section contains a lot of information about executing SQL statements using the jOOQ API
3.3.5. jOOQ for PROs
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ isn't just a library that helps you build and execute SQL against your generated, compilable schema. jOOQ ships with a lot of tools. Here are some of the most important tools shipped with jOOQ:
- jOOQ's Execute Listeners: jOOQ allows you to hook your custom execute listeners into jOOQ's SQL statement execution lifecycle in order to centrally coordinate any arbitrary operation performed on SQL being executed. Use this for logging, identity generation, SQL tracing, performance measurements, etc.
- Logging: jOOQ has a standard DEBUG logger built-in, for logging and tracing all your executed SQL statements and fetched result sets
- Stored Procedures: jOOQ supports stored procedures and functions of your favourite database. All routines and user-defined types are generated and can be included in jOOQ's SQL building API as function references.
- Batch execution: Batch execution is important when executing a big load of SQL statements. jOOQ simplifies these operations compared to JDBC
- Exporting and Importing: jOOQ ships with an API to easily export/import data in various formats
If you're a power user of your favourite, feature-rich database, jOOQ will help you access all of your database's vendor-specific features, such as OLAP features, stored procedures, user-defined types, vendor-specific SQL, functions, etc. Examples are given throughout this manual.
3.4. Tutorials
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Don't have time to read the full manual? Here are a couple of tutorials that will get you into the most essential parts of jOOQ as quick as possible.
3.4.1. jOOQ in 7 easy steps
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This manual section is intended for new users, to help them get a running application with jOOQ, quickly.
3.4.1.1. Step 1: Preparation
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
If you haven't already downloaded it, download jOOQ:
https://www.jooq.org/download
Alternatively, you can create a Maven dependency to download jOOQ artefacts:
Open Source Edition
<dependency> <groupId>org.jooq</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Commercial Editions (Java 17+)
<!-- 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.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.pro</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.pro</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Commercial Editions (Java 11+)
<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution --> <dependency> <groupId>org.jooq.pro-java-11</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.pro-java-11</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.pro-java-11</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</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-java-8</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.pro-java-8</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.pro-java-8</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Commercial Editions (Free Trial, Java 17+)
<!-- 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.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.trial</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.trial</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Commercial Editions (Free Trial, Java 11+)
<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution --> <dependency> <groupId>org.jooq.trial-java-11</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.trial-java-11</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.trial-java-11</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Commercial Editions (Free Trial, Java 8+)
<!-- Note: These aren't hosted on Maven Central. Import them manually from your distribution --> <dependency> <groupId>org.jooq.trial-java-8</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.trial-java-8</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.trial-java-8</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</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.17.16</version> </dependency> <!-- These may not be required, unless you use the GenerationTool manually for code generation --> <dependency> <groupId>org.jooq.pro-java-6</groupId> <artifactId>jooq-meta</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>org.jooq.pro-java-6</groupId> <artifactId>jooq-codegen</artifactId> <version>3.17.16</version> </dependency>
Note that only the jOOQ Open Source Edition is available from Maven Central. If you're using the jOOQ Professional Edition or the jOOQ Enterprise Edition, you will have to manually install jOOQ in your local Nexus, or in your local Maven cache. For more information, please refer to the licensing pages.
Please refer to the manual's section about Code generation configuration to learn how to use jOOQ's code generator with Maven.
For this example, we'll be using MySQL. If you haven't already downloaded MySQL Connector/J, download it here:
https://dev.mysql.com/downloads/connector/j/
If you don't have a MySQL instance up and running yet, get it from https://www.mysql.com or https://hub.docker.com/_/mysql now!
3.4.1.2. Step 2: Your database
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
We're going to create a database called "library" and a corresponding "author" table. Connect to MySQL via your command line client and type the following:
CREATE DATABASE `library`; USE `library`; CREATE TABLE `author` ( `id` int NOT NULL, `first_name` varchar(255) DEFAULT NULL, `last_name` varchar(255) DEFAULT NULL, PRIMARY KEY (`id`) );
3.4.1.3. Step 3: Code generation
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In this step, we're going to use jOOQ's command line tools to generate classes that map to the Author table we just created. More detailed information about how to set up the jOOQ code generator can be found here:
jOOQ manual pages about setting up the code generator
The easiest way to generate a schema is to copy the jOOQ jar files (there should be 3) and the MySQL Connector jar file to a temporary directory. Then, create a library.xml that looks like this:
<?xml version="1.0" encoding="UTF-8" standalone="yes"?> <configuration> <!-- Configure the database connection here --> <jdbc> <driver>com.mysql.cj.jdbc.Driver</driver> <url>jdbc:mysql://localhost:3306/library</url> <user>root</user> <password></password> </jdbc> <generator> <!-- The default code generator. You can override this one, to generate your own code style. Supported generators: - org.jooq.codegen.JavaGenerator - org.jooq.codegen.KotlinGenerator - 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.jooq.meta.[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 (<username/>
or <user/>
) with whatever user has the appropriate privileges to query the database meta data. You'll also want to look at the other values and replace as necessary. Here are the two interesting properties:
<packageName/>
- set this to the parent package you want to create for the generated classes. Setting the value to test.generated
will cause the test.generated.tables.Author
and test.generated.tables.records.AuthorRecord
classes to be created
<directory/>
- the directory to output the generated classes to.
Once you have the JAR files and library.xml in your temp directory, type this on a Windows machine:
java -classpath jooq-3.17.16.jar;^ jooq-meta-3.17.16.jar;^ jooq-codegen-3.17.16.jar;^ reactive-streams-1.0.3.jar;^ r2dbc-spi-0.9.0.RELEASE.jar;^ jakarta.xml.bind-api-3.0.0.jar;^ mysql-connector-java.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.17.16.jar:\ jooq-meta-3.17.16.jar:\ jooq-codegen-3.17.16.jar:\ reactive-streams-1.0.3.jar:\ r2dbc-spi-0.9.0.RELEASE.jar:\ jakarta.xml.bind-api-3.0.0.jar:\ mysql-connector-java.jar:. \ org.jooq.codegen.GenerationTool library.xml
- 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.17.16 is being used.
- If you're using a linux style shell on Windows, but a Windows JDK/JRE, you still need to use semi-colons in your classpath! (
;
) In git-bash, you might have to quote your classpath ("jooq-3.17.16.jar;jooq-meta-3.17.16.jar;..."
)
If everything has worked, you should see this in your console output:
Nov 1, 2011 7:25:06 PM org.jooq.impl.JooqLogger info INFO: Initialising properties : /library.xml Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Database parameters Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: ---------------------------------------------------------- Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: dialect : MYSQL Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: schema : library Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: target dir : C:/workspace/MySQLTest/src Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: target package : test.generated Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: ---------------------------------------------------------- Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Emptying : C:/workspace/MySQLTest/src/test/generated Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Generating classes in : C:/workspace/MySQLTest/src/test/generated Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Generating schema : Library.java Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Schema generated : Total: 122.18ms Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Sequences fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Tables fetched : 5 (5 included, 0 excluded) Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Generating tables : C:/workspace/MySQLTest/src/test/generated/tables Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: ARRAYs fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Enums fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: UDTs fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Generating table : Author.java Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Tables generated : Total: 680.464ms, +558.284ms Nov 1, 2011 7:25:07 PM org.jooq.impl.JooqLogger info INFO: Generating Keys : C:/workspace/MySQLTest/src/test/generated/tables Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Keys generated : Total: 718.621ms, +38.157ms Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Generating records : C:/workspace/MySQLTest/src/test/generated/tables/records Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Generating record : AuthorRecord.java Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Table records generated : Total: 782.545ms, +63.924ms Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Routines fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: Packages fetched : 0 (0 included, 0 excluded) Nov 1, 2011 7:25:08 PM org.jooq.impl.JooqLogger info INFO: GENERATION FINISHED! : Total: 791.688ms, +9.143ms
3.4.1.4. Step 4: Connect to your database
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Let's just write a vanilla main class in the project containing the generated classes:
// For convenience, always static import your generated tables and jOOQ functions to decrease verbosity: import static test.generated.Tables.*; import static org.jooq.impl.DSL.*; import java.sql.*; public class Main { public static void main(String[] args) { String userName = "root"; String password = ""; String url = "jdbc:mysql://localhost:3306/library"; // Connection is the only JDBC resource that we need // PreparedStatement and ResultSet are handled by jOOQ, internally try (Connection conn = DriverManager.getConnection(url, userName, password)) { // ... } // For the sake of this tutorial, let's keep exception handling simple catch (Exception e) { e.printStackTrace(); } } }
This is pretty standard code for establishing a MySQL connection.
3.4.1.5. Step 5: Querying
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Let's add a simple query constructed with jOOQ's query DSL:
DSLContext create = DSL.using(conn, SQLDialect.MYSQL); Result<Record> result = create.select().from(AUTHOR).fetch();
First get an instance of DSLContext
so we can write a simple SELECT
query. We pass an instance of the MySQL connection to DSL
. Note that the DSLContext doesn't close the connection. We'll have to do that ourselves.
We then use jOOQ's query DSL to return an instance of Result. We'll be using this result in the next step.
3.4.1.6. Step 6: Iterating
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
After the line where we retrieve the results, let's iterate over the results and print out the data:
for (Record r : result) { Integer id = r.getValue(AUTHOR.ID); String firstName = r.getValue(AUTHOR.FIRST_NAME); String lastName = r.getValue(AUTHOR.LAST_NAME); System.out.println("ID: " + id + " first name: " + firstName + " last name: " + lastName); }
The full program should now look like this:
package test; // For convenience, always static import your generated tables and // jOOQ functions to decrease verbosity: import static test.generated.Tables.*; import static org.jooq.impl.DSL.*; import java.sql.*; import org.jooq.*; import org.jooq.impl.*; public class Main { /** * @param args */ public static void main(String[] args) { String userName = "root"; String password = ""; String url = "jdbc:mysql://localhost:3306/library"; // Connection is the only JDBC resource that we need // PreparedStatement and ResultSet are handled by jOOQ, internally try (Connection conn = DriverManager.getConnection(url, userName, password)) { DSLContext create = DSL.using(conn, SQLDialect.MYSQL); Result<Record> result = create.select().from(AUTHOR).fetch(); for (Record r : result) { Integer id = r.getValue(AUTHOR.ID); String firstName = r.getValue(AUTHOR.FIRST_NAME); String lastName = r.getValue(AUTHOR.LAST_NAME); System.out.println("ID: " + id + " first name: " + firstName + " last name: " + lastName); } } // For the sake of this tutorial, let's keep exception handling simple catch (Exception e) { e.printStackTrace(); } } }
3.4.1.7. Step 7: Explore!
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ has grown to be a comprehensive SQL library. For more information, please consider the documentation:
https://www.jooq.org/learn
... explore the Javadoc:
https://www.jooq.org/javadoc/latest/
... or join the news group:
https://groups.google.com/forum/#!forum/jooq-user
This tutorial is the courtesy of Ikai Lan. See the original source here:
https://ikaisays.com/2011/11/01/getting-started-with-jooq-a-tutorial/
3.4.2. Using jOOQ with Flyway
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When performing database migrations, we at Data Geekery recommend using jOOQ with Flyway - Database Migrations Made Easy. In this chapter, we're going to look into a simple way to get started with the two frameworks.
Philosophy
There are a variety of ways how jOOQ and Flyway could interact with each other in various development setups. In this tutorial we're going to show just one variant of such framework team play - a variant that we find particularly compelling for most use cases.
The general philosophy behind the following approach can be summarised as this:
- 1. Database increment
- 2. Database migration
- 3. Code re-generation
- 4. Development
The four steps above can be repeated time and again, every time you need to modify something in your database. More concretely, let's consider:
- 1. Database increment - You need a new column in your database, so you write the necessary DDL in a Flyway script
- 2. Database migration - This Flyway script is now part of your deliverable, which you can share with all developers who can migrate their databases with it, the next time they check out your change
- 3. Code re-generation - Once the database is migrated, you regenerate all jOOQ artefacts (see code generation), locally
- 4. Development - You continue developing your business logic, writing code against the updated, generated database schema
Maven Project Configuration - Properties
The following properties are defined in our pom.xml, to be able to reuse them between plugin configurations:
<properties> <db.url>jdbc:h2:~/flyway-test</db.url> <db.username>sa</db.username> </properties>
0. Maven Project Configuration - Dependencies
While jOOQ and Flyway could be used in standalone migration scripts, in this tutorial, we'll be using Maven for the standard project setup. You will also find the source code of this tutorial on GitHub at https://github.com/jOOQ/jOOQ/tree/main/jOOQ-examples/jOOQ-flyway-example, and the full pom.xml file here.
These are the dependencies that we're using in our Maven configuration:
<!-- We'll add the latest version of jOOQ and our JDBC driver - in this case H2 --> <dependency> <!-- Use org.jooq for the Open Source Edition org.jooq.pro for commercial editions with Java 17 support, org.jooq.pro-java-11 for commercial editions with Java 11 support, org.jooq.pro-java-8 for commercial editions with Java 8 support, org.jooq.trial for the free trial edition with Java 17 support, org.jooq.trial-java-11 for the free trial edition with Java 11 support, org.jooq.trial-java-8 for the free trial edition with Java 8 support Note: Only the Open Source Edition is hosted on Maven Central. Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org --> <groupId>org.jooq</groupId> <artifactId>jooq</artifactId> <version>3.17.16</version> </dependency> <dependency> <groupId>com.h2database</groupId> <artifactId>h2</artifactId> <version>1.4.197</version> </dependency> <!-- For improved logging, we'll be using log4j via slf4j to see what's going on during migration and code generation --> <dependency> <groupId>org.apache.logging.log4j</groupId> <artifactId>log4j-slf4j-impl</artifactId> <version>2.11.0</version> </dependency> <!-- To ensure our code is working, we're using JUnit --> <dependency> <groupId>junit</groupId> <artifactId>junit</artifactId> <version>4.11</version> <scope>test</scope> </dependency>
0. Maven Project Configuration - Plugins
After the dependencies, let's simply add the Flyway and jOOQ Maven plugins like so. The Flyway plugin:
<plugin> <groupId>org.flywaydb</groupId> <artifactId>flyway-maven-plugin</artifactId> <version>3.0</version> <!-- Note that we're executing the Flyway plugin in the "generate-sources" phase --> <executions> <execution> <phase>generate-sources</phase> <goals> <goal>migrate</goal> </goals> </execution> </executions> <!-- Note that we need to prefix the db/migration path with filesystem: to prevent Flyway from looking for our migration scripts only on the classpath --> <configuration> <url>${db.url}</url> <user>${db.username}</user> <locations> <location>filesystem:src/main/resources/db/migration</location> </locations> </configuration> </plugin>
The above Flyway Maven plugin configuration will read and execute all database migration scripts from src/main/resources/db/migration
prior to compiling Java source code. While the official Flyway documentation may suggest that migrations be done in the compile
phase, the jOOQ code generator relies on such migrations having been done prior to code generation.
After the Flyway plugin, we'll add the jOOQ Maven Plugin. For more details, please refer to the manual's section about the code generation configuration.
<plugin> <!-- Use org.jooq for the Open Source Edition org.jooq.pro for commercial editions with Java 17 support, org.jooq.pro-java-11 for commercial editions with Java 11 support, org.jooq.pro-java-8 for commercial editions with Java 8 support, org.jooq.trial for the free trial edition with Java 17 support, org.jooq.trial-java-11 for the free trial edition with Java 11 support, org.jooq.trial-java-8 for the free trial edition with Java 8 support Note: Only the Open Source Edition is hosted on Maven Central. Install the others locally using the provided scripts, or access them from here: https://repo.jooq.org --> <groupId>org.jooq</groupId> <artifactId>jooq-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.17.16:generate (default) @ jooq-flyway-example --- [INFO] --- jooq-codegen-maven:3.17.16:generate (default) @ jooq-flyway-example --- [INFO] Using this configuration: ... [INFO] Generating schemata : Total: 1 [INFO] Generating schema : FlywayTest.java [INFO] ---------------------------------------------------------- [....] [INFO] GENERATION FINISHED! : Total: 337.576ms, +4.299ms
4. Development
Note that all of the previous steps are executed automatically, every time someone adds new migration scripts to the Maven module. For instance, a team member might have committed a new migration script, you check it out, rebuild and get the latest jOOQ-generated sources for your own development or integration-test database.
Now, that these steps are done, you can proceed writing your database queries. Imagine the following test case
import org.jooq.Result; import org.jooq.impl.DSL; import org.junit.Test; import java.sql.DriverManager; import static java.util.Arrays.asList; import static org.jooq.example.flyway.db.h2.Tables.*; import static org.junit.Assert.assertEquals; public class AfterMigrationTest { @Test public void testQueryingAfterMigration() throws Exception { try (Connection c = DriverManager.getConnection("jdbc:h2:~/flyway-test", "sa", "")) { Result<?> result = DSL.using(c) .select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.ID, BOOK.TITLE ) .from(AUTHOR) .join(BOOK) .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .orderBy(BOOK.ID.asc()) .fetch(); assertEquals(4, result.size()); assertEquals(asList(1, 2, 3, 4), result.getValues(BOOK.ID)); } } }
Reiterate
The power of this approach becomes clear once you start performing database modifications this way. Let's assume that the French guy on our team prefers to have things his way:
-- V4__le_french.sql ALTER TABLE flyway_test.book ALTER COLUMN title RENAME TO le_titre;
They check it in, you check out the new database migration script, run
mvn clean install
And then observing the log output:
[INFO] --- flyway-maven-plugin:3.0:migrate (default) @ jooq-flyway-example --- [INFO] --- flyway-maven-plugin:3.0:migrate (default) @ jooq-flyway-example --- [INFO] Database: jdbc:h2:~/flyway-test (H2 1.4) [INFO] Validated 4 migrations (execution time 00:00.005s) [INFO] Current version of schema "PUBLIC": 3 [INFO] Migrating schema "PUBLIC" to version 4 [INFO] Successfully applied 1 migration to schema "PUBLIC" (execution time 00:00.016s).
So far so good, but later on:
[ERROR] COMPILATION ERROR : [INFO] ------------------------------------------------------------- [ERROR] C:\...\jOOQ-flyway-example\src\test\java\AfterMigrationTest.java:[24,19] error: cannot find symbol [INFO] 1 error
When we go back to our Java integration test, we can immediately see that the TITLE column is still being referenced, but it no longer exists:
public class AfterMigrationTest { @Test public void testQueryingAfterMigration() throws Exception { try (Connection c = DriverManager.getConnection("jdbc:h2:~/flyway-test", "sa", "")) { Result<?> result = DSL.using(c) .select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.ID, BOOK.TITLE // ^^^^^ This column no longer exists. We'll have to rename it to LE_TITRE ) .from(AUTHOR) .join(BOOK) .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .orderBy(BOOK.ID.asc()) .fetch(); assertEquals(4, result.size()); assertEquals(asList(1, 2, 3, 4), result.getValues(BOOK.ID)); } } }
Automation
The above steps can be automated in your build using another third party called testcontainers. Please look at this article here for examples on how to do that: https://blog.jooq.org/using-testcontainers-to-generate-jooq-code/
Conclusion
This tutorial shows very easily how you can build a rock-solid development process using Flyway and jOOQ to prevent SQL-related errors very early in your development lifecycle - immediately at compile time, rather than in production!
Please, visit the Flyway website for more information about Flyway.
3.4.3. Using jOOQ with jbang
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jbang allows for quickly working with all sorts of Java libraries without the hassle of setting up environments, dependencies, etc. This catalog allows for using jOOQ's code generator right away on an existing database.
For more information on jbang, see:
An example
In a shell, type
git clone https://github.com/jOOQ/jbang-example cd jbang-example jbang Example.java
In order to re-generate the example code, e.g. when your schema changes, just type:
jbang codegen@jooq db.xml
If you prefer working with a pre-existing database, just edit the db.xml
file and point it to your database. Add the JDBC driver dependency like this:
jbang --deps org.postgresql:postgresql:RELEASE codegen@jooq db.xml
To override the jOOQ version from the default RELEASE
to a specific version, use
jbang -Djooq.version=<version> codegen@jooq db.xml
3.5. jOOQ and Java 8
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Java 8 has introduced a great set of enhancements, among which lambda expressions and the new java.util.stream.Stream
. These new constructs align very well with jOOQ's fluent API as can be seen in the following examples:
jOOQ and lambda expressions
jOOQ's RecordMapper API is fully Java-8-ready, which basically means that it is a SAM (Single Abstract Method) type, which can be instanciated using a lambda expression. Consider this example:
try (Connection c = getConnection()) { String sql = "select schema_name, is_default " + "from information_schema.schemata " + "order by schema_name"; DSL.using(c) .fetch(sql) // We can use lambda expressions to map jOOQ Records .map(rs -> new Schema( rs.getValue("SCHEMA_NAME", String.class), rs.getValue("IS_DEFAULT", boolean.class) )) // ... and then profit from the new Collection methods .forEach(System.out::println); }
The above example shows how jOOQ's Result.map() method can receive a lambda expression that implements RecordMapper to map from jOOQ Records to your custom types.
jOOQ and the Streams API
jOOQ's Result type extends java.util.List
, which opens up access to a variety of new Java features in Java 8. The following example shows how easy it is to transform a jOOQ Result
containing INFORMATION_SCHEMA
meta data to produce DDL statements:
DSL.using(c) .select( COLUMNS.TABLE_NAME, COLUMNS.COLUMN_NAME, COLUMNS.TYPE_NAME ) .from(COLUMNS) .orderBy( COLUMNS.TABLE_CATALOG, COLUMNS.TABLE_SCHEMA, COLUMNS.TABLE_NAME, COLUMNS.ORDINAL_POSITION ) .fetch() // jOOQ ends here .stream() // JDK 8 Streams start here .collect(groupingBy( r -> r.getValue(COLUMNS.TABLE_NAME), LinkedHashMap::new, mapping( r -> new Column( r.getValue(COLUMNS.COLUMN_NAME), r.getValue(COLUMNS.TYPE_NAME) ), toList() ) )) .forEach( (table, columns) -> { // Just emit a CREATE TABLE statement System.out.println( "CREATE TABLE " + table + " ("); // Map each "Column" type into a String // containing the column specification, // and join them using comma and // newline. Done! System.out.println( columns.stream() .map(col -> " " + col.name + " " + col.type) .collect(Collectors.joining(",\n")) ); System.out.println(");"); } );
The above example is explained more in depth in this blog post: https://blog.jooq.org/java-8-friday-no-more-need-for-orms/. For more information about Java 8, consider these resources:
3.6. jOOQ and JavaFX
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
One of the major improvements of Java 8 is the introduction of JavaFX into the JavaSE. With jOOQ and Java 8 Streams and lambdas, it is now very easy and idiomatic to transform SQL results into JavaFX XYChart.Series
or other, related objects:
Creating a bar chart from a jOOQ Result
As we've seen in the previous section about jOOQ and Java 8, jOOQ integrates seamlessly with Java 8's Streams API. The fluent style can be maintained throughout the data transformation chain.
In this example, we're going to use Open Data from the world bank to show a comparison of countries GDP and debts:
DROP SCHEMA IF EXISTS world; CREATE SCHEMA world; CREATE TABLE world.countries ( code CHAR(2) NOT NULL, year INT NOT NULL, gdp_per_capita DECIMAL(10, 2) NOT NULL, govt_debt DECIMAL(10, 2) NOT NULL ); INSERT INTO world.countries VALUES ('CA', 2009, 40764, 51.3), ('CA', 2010, 47465, 51.4), ('CA', 2011, 51791, 52.5), ('CA', 2012, 52409, 53.5), ('DE', 2009, 40270, 47.6), ('DE', 2010, 40408, 55.5), ('DE', 2011, 44355, 55.1), ('DE', 2012, 42598, 56.9), ('FR', 2009, 40488, 85.0), ('FR', 2010, 39448, 89.2), ('FR', 2011, 42578, 93.2), ('FR', 2012, 39759,103.8), ('GB', 2009, 35455,121.3), ('GB', 2010, 36573, 85.2), ('GB', 2011, 38927, 99.6), ('GB', 2012, 38649,103.2), ('IT', 2009, 35724,121.3), ('IT', 2010, 34673,119.9), ('IT', 2011, 36988,113.0), ('IT', 2012, 33814,131.1), ('JP', 2009, 39473,166.8), ('JP', 2010, 43118,174.8), ('JP', 2011, 46204,189.5), ('JP', 2012, 46548,196.5), ('RU', 2009, 8616, 8.7), ('RU', 2010, 10710, 9.1), ('RU', 2011, 13324, 9.3), ('RU', 2012, 14091, 9.4), ('US', 2009, 46999, 76.3), ('US', 2010, 48358, 85.6), ('US', 2011, 49855, 90.1), ('US', 2012, 51755, 93.8);
Once this data is set up (e.g. in an H2 or PostgreSQL database), we'll run jOOQ's code generator and implement the following code to display our chart:
CategoryAxis xAxis = new CategoryAxis(); NumberAxis yAxis = new NumberAxis(); xAxis.setLabel("Country"); yAxis.setLabel("% of GDP"); BarChart<String, Number> bc = new BarChart<String, Number>(xAxis, yAxis); bc.setTitle("Government Debt"); bc.getData().addAll( // SQL data transformation, executed in the database // ------------------------------------------------- DSL.using(connection) .select( COUNTRIES.YEAR, COUNTRIES.CODE, COUNTRIES.GOVT_DEBT) .from(COUNTRIES) .join( table( select(COUNTRIES.CODE, avg(COUNTRIES.GOVT_DEBT).as("avg")) .from(COUNTRIES) .groupBy(COUNTRIES.CODE) ).as("c1") ) .on(COUNTRIES.CODE.eq(field(name("c1", COUNTRIES.CODE.getName()), String.class))) // order countries by their average projected value .orderBy( field(name("avg")), COUNTRIES.CODE, COUNTRIES.YEAR) // The result produced by the above statement looks like this: // +----+----+---------+ // |year|code|govt_debt| // +----+----+---------+ // |2009|RU | 8.70| // |2010|RU | 9.10| // |2011|RU | 9.30| // |2012|RU | 9.40| // |2009|CA | 51.30| // +----+----+---------+ // Java data transformation, executed in application memory // -------------------------------------------------------- // Group results by year, keeping sort order in place .fetchGroups(COUNTRIES.YEAR) // Stream<Entry<Integer, Result<Record3<BigDecimal, String, Integer>>>> .entrySet() .stream() // Map each entry into a { Year -> Projected value } series .map(entry -> new XYChart.Series<>( entry.getKey().toString(), observableArrayList( // Map each country record into a chart Data object entry.getValue() .map(country -> new XYChart.Data<String, Number>( country.getValue(COUNTRIES.CODE), country.getValue(COUNTRIES.GOVT_DEBT) )) ) )) .collect(toList()) );
The above example uses basic SQL-92 syntax where the countries are ordered using aggregate information from a derived table, which is supported in all databases. If you're using a database that supports window functions, e.g. PostgreSQL or any commercial database, you could have also written a simpler query like this:00
DSL.using(connection) .select( COUNTRIES.YEAR, COUNTRIES.CODE, COUNTRIES.GOVT_DEBT) .from(COUNTRIES) // order countries by their average projected value .orderBy( DSL.avg(COUNTRIES.GOVT_DEBT).over(partitionBy(COUNTRIES.CODE)), COUNTRIES.CODE, COUNTRIES.YEAR) .fetch() ; return bc;
When executed, we'll get nice-looking bar charts like these:
The complete example can be downloaded and run from GitHub:
https://github.com/jOOQ/jOOQ/tree/main/jOOQ-examples/jOOQ-javafx-example
3.7. jOOQ and Nashorn
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
With Java 8 and the new built-in JavaScript engine Nashorn, a whole new ecosystem of software can finally make easy use of jOOQ in server-side JavaScript. A very simple example can be seen here:
// Let's assume these objects were generated // by the jOOQ source code generator var Tables = Java.type("org.jooq.db.h2.information_schema.Tables"); var t = Tables.TABLES; var c = Tables.COLUMNS; // This is the equivalent of Java's static imports var count = DSL.count; var row = DSL.row; // We can now execute the following query: print( DSL.using(conn) .select( t.TABLE_SCHEMA, t.TABLE_NAME, c.COLUMN_NAME) .from(t) .join(c) .on(row(t.TABLE_SCHEMA, t.TABLE_NAME) .eq(c.TABLE_SCHEMA, c.TABLE_NAME)) .orderBy( t.TABLE_SCHEMA.asc(), t.TABLE_NAME.asc(), c.ORDINAL_POSITION.asc()) .fetch() );
3.8. jOOQ and Scala
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
As any other library, jOOQ can be easily used in Scala, taking advantage of the many Scala language features such as for example:
- Optional "." to dereference methods from expressions
- Optional "(" and ")" to delimit method argument lists
- Optional ";" at the end of a Scala statement
- Type inference using "var" and "val" keywords
- Lambda expressions and for-comprehension syntax for record iteration and data type conversion
But jOOQ also leverages other useful Scala features, such as
- implicit defs for operator overloading
- Scala Macros (soon to come)
All of the above heavily improve jOOQ's querying DSL API experience for Scala developers.
A short example jOOQ application in Scala might look like this:
import collection.JavaConversions._ // Import implicit defs for iteration over org.jooq.Result // import java.sql.DriverManager // // import org.jooq._ // import org.jooq.impl._ // import org.jooq.impl.DSL._ // import org.jooq.examples.scala.h2.Tables._ // import org.jooq.scalaextensions.Conversions._ // Import implicit defs for overloaded jOOQ/SQL operators // object Test { // def main(args: Array[String]): Unit = { // val c = DriverManager.getConnection("jdbc:h2:~/test", "sa", ""); // Standard JDBC connection val e = DSL.using(c, SQLDialect.H2); // val x = AUTHOR as "x" // SQL-esque table aliasing // for (r <- e // Iteration over Result. "r" is an org.jooq.Record3 select ( // BOOK.ID * BOOK.AUTHOR_ID, // Using the overloaded "*" operator BOOK.ID + BOOK.AUTHOR_ID * 3 + 4, // Using the overloaded "+" operator BOOK.TITLE || " abc" || " xy" // Using the overloaded "||" operator ) // from BOOK // No need to use parentheses or "." here leftOuterJoin ( // select (x.ID, x.YEAR_OF_BIRTH) // Dereference fields from aliased table from x // limit 1 // asTable x.getName() // ) // on BOOK.AUTHOR_ID === x.ID // Using the overloaded "===" operator where (BOOK.ID <> 2) // Using the olerloaded "<>" operator or (BOOK.TITLE in ("O Alquimista", "Brida")) // Neat IN predicate expression fetch // ) { // println(r) // } // } // }
For more details about jOOQ's Scala integration, please refer to the manual's section about SQL building with Scala.
3.9. jOOQ and Groovy
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
As any other library, jOOQ can be easily used in Groovy, taking advantage of the many Groovy language features such as for example:
- Optional ";" at the end of a Groovy statement
- Type inference for local variables
A short example jOOQ application in Groovy might look like this:
package org.jooq.groovy import static org.jooq.impl.DSL.* import static org.jooq.groovy.example.h2.Tables.* import groovy.sql.Sql import org.jooq.* import org.jooq.impl.DSL sql = Sql.newInstance('jdbc:h2:~/groovy-test', 'sa', '', 'org.h2.Driver'); a = AUTHOR.as("a"); b = BOOK.as("b") DSL.using(sql.connection) .select(a.FIRST_NAME, a.LAST_NAME, b.TITLE) .from(a) .join(b).on(a.ID.eq(b.AUTHOR_ID)) .fetchInto ({ r -> println( "${r.getValue(a.FIRST_NAME)} " + "${r.getValue(a.LAST_NAME)} " + "has written ${r.getValue(b.TITLE)}" ) } as RecordHandler)
Note that while Groovy supports some means of operator overloading, we think that these means should be avoided in a jOOQ integration. For instance, a + b
in Groovy maps to a formal a.plus(b)
method invocation, and jOOQ provides the required synonyms in its API to help you write such expressions. Nonetheless, Groovy only offers little typesafety, and as such, operator overloading can lead to many runtime issues.
Another caveat of Groovy operator overloading is the fact that operators such as ==
or >=
map to a.equals(b)
, a.compareTo(b) == 0
, a.compareTo(b) >= 0
respectively. This behaviour does not make sense in a fluent API such as jOOQ.
3.10. jOOQ and Kotlin
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
As any other library, jOOQ can be easily used in Kotlin, taking advantage of the many Kotlin language features such as for example:
- Optional ";" at the end of a Kotlin statement
- Type inference for local variables
A short example jOOQ application in Kotlin might look like this:
package org.jooq.example.kotlin import java.util.Properties import org.jooq.* import org.jooq.impl.DSL import org.jooq.impl.DSL.* import org.jooq.example.db.h2.Tables.* fun main(args: Array<String>) { val properties = Properties(); properties.load(Properties::class.java.getResourceAsStream("/config.properties")); DSL.using( properties.getProperty("db.url"), properties.getProperty("db.username"), properties.getProperty("db.password") ).use { ctx -> val a = AUTHOR val b = BOOK ctx.select(a.FIRST_NAME, a.LAST_NAME, b.TITLE) .from(a) .join(b).on(a.ID.eq(b.AUTHOR_ID)) .orderBy(1, 2, 3) .forEach { println("${it[b.TITLE]} by ${it[a.FIRST_NAME]} ${it[a.LAST_NAME]}") } } }
Note that Kotlin supports some means of operator overloading. For instance, a + b
in Kotlin maps to a formal a.plus(b)
method invocation, and jOOQ provides the required synonyms in its API to help you write such expressions.
One particularly nice language feature is the fact that [square brackets] allow for accessing any object's contents via get()
and set()
methods. Instead of using the above value1()
, value2()
, and value3()
methods, we could also iterate as such:
ctx.select(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE) .from(AUTHOR) .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .orderBy(1, 2, 3) .forEach { println("${it[BOOK.TITLE]} by ${it[AUTHOR.FIRST_NAME]} ${it[AUTHOR.LAST_NAME]}") // Notice: ^^^^^^^^^^^^ ^^^^^^^^^^^^^^^^^^^ ^^^^^^^^^^^^^^^^^^ }
A caveat of Kotlin operator overloading is the fact that operators such as ==
or >=
map to a.equals(b)
, a.compareTo(b) == 0
, a.compareTo(b) >= 0
respectively. This behaviour does not make sense in a fluent API such as jOOQ.
3.11. jOOQ and NoSQL
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ users often get excited about jOOQ's intuitive API and would then wish for NoSQL support.
There are a variety of NoSQL databases that implement some sort of proprietary query language. Some of these query languages even look like SQL. Examples are JCR-SQL2, CQL (Cassandra Query Language), Cypher (Neo4j's Query Language), and many more.
Mapping the jOOQ API onto these alternative query languages would be a very poor fit and a leaky abstraction. We believe in the power and expressivity of the SQL standard and its various dialects. Databases that extend this standard too much, or implement it not thoroughly enough are often not suitable targets for jOOQ. It would be better to build a new, dedicated API for just that one particular query language.
jOOQ is about SQL, and about SQL alone. Read more about our visions in the manual's preface.
3.12. jOOQ and JPA
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Just because you're using jOOQ doesn't mean you have to use it for everything!
When introducing jOOQ into an existing application that uses JPA, the common question is always: "Should we replace JPA by jOOQ?" and "How do we proceed doing that?"
Beware that jOOQ is not a replacement for JPA. Think of jOOQ as a complement. JPA (and ORMs in general) try to solve the object graph persistence problem. In short, this problem is about
- Loading an entity graph into client memory from a database
- Manipulating that graph in the client
- Storing the modification back to the database
As the above graph gets more complex, a lot of tricky questions arise like:
- What's the optimal order of SQL DML operations for loading and storing entities?
- How can we batch the commands more efficiently?
- How can we keep the transaction footprint as low as possible without compromising on ACID?
- How can we implement optimistic locking?
jOOQ only has some of the answers.
While jOOQ does offer updatable records that help running simple CRUD, a batch API, optimistic locking capabilities, jOOQ mainly focuses on executing actual SQL statements.
SQL is the preferred language of database interaction, when any of the following are given:
- You run reports and analytics on large data sets directly in the database
- You import / export data using ETL
- You run complex business logic as SQL queries
Whenever SQL is a good fit, jOOQ is a good fit. Whenever you're persisting an object graph, JPA is a good fit. Though note that starting with jOOQ 3.15 you can also load trees with the MULTISET_AGG function and the MULTISET value constructor very easily.
And sometimes, it's best to combine both
3.13. Build your own
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In order to build jOOQ (Open Source Edition) yourself, please download the sources from https://github.com/jOOQ/jOOQ and use Maven to build jOOQ, preferably in Eclipse. The jOOQ Open Source Edition requires Java 8+ to compile and run. The commercial jOOQ Editions require Java 8+ or Java 6+ to compile and run, depending on the distribution.
Some useful hints to build jOOQ yourself:
- Get the latest version of Git or EGit
- Get the latest version of Maven or M2E
- Check out the jOOQ sources from https://github.com/jOOQ/jOOQ
- Optionally, import Maven artefacts into an Eclipse workspace using the following command (see the maven-eclipse-plugin documentation for details):
-
mvn eclipse:eclipse
-
- Build the
jooq-parent
artefact by using any of these commands:-
mvn clean package
create .jar files in${project.build.directory}
-
mvn clean install
install the .jar files in your local repository (e.g.~/.m2
) -
mvn clean {goal} -Dmaven.test.skip=true
don't run unit tests when building artefacts
-
3.14. jOOQ and backwards-compatibility
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Semantic versioning
jOOQ's understanding of backwards compatibility is inspired by the rules of semantic versioning according to https://semver.org. Those rules impose a versioning scheme [X].[Y].[Z] that can be summarised as follows:
- If a patch release includes bugfixes, performance improvements and API-irrelevant new features, [Z] is incremented by one.
- If a minor release includes backwards-compatible, API-relevant new features, [Y] is incremented by one and [Z] is reset to zero.
- If a major release includes backwards-incompatible, API-relevant new features, [X] is incremented by one and [Y], [Z] are reset to zero.
jOOQ's understanding of backwards-compatibility
Backwards-compatibility is important to jOOQ. You've chosen jOOQ as a strategic SQL engine and you don't want your SQL to break.
However, there are some elements of API evolution that would be considered backwards-incompatible in other APIs, but not in jOOQ. As discussed later on in the section about jOOQ's query DSL API, much of jOOQ's API is indeed an internal domain-specific language implemented mostly using Java interfaces. Adding language elements to these interfaces means any of these actions:
- Adding methods to the interface
- Overloading methods for convenience
- Changing the type hierarchy of interfaces (including raw type or binary compatibility implications)
It becomes obvious that it would be impossible to add new language elements (e.g. new SQL functions, new SELECT clauses) to the API without breaking any client code that actually implements those interfaces. Hence, the following rules should be observed:
- jOOQ's DSL interfaces should not be implemented by client code! Extend only those extension points that are explicitly documented as "extendable" (e.g. custom QueryParts).
- Generated code implements such interfaces and extends internal classes, and as such is recommended to be re-generated with a matching code generator version every time the runtime library is upgraded.
- Binary compatibility can be expected from patch releases, but not from minor releases as it is not practical to maintain binary compatibility in an internal DSL.
- Source compatibility can be expected from patch and minor releases, the exception being raw type compatibility (see #11879), and rare exceptions where API design is clearly lacking.
- Behavioural compatibility can be expected from patch and minor releases.
- Any jOOQ SPI
XYZ
that is meant to be implemented ships with aDefaultXYZ
orAbstractXYZ
, which can be used safely as a default implementation.
jOOQ-codegen and jOOQ-meta
While a reasonable amount of care is spent to maintain these two modules under the rules of semantic versioning, it may well be that minor releases introduce backwards-incompatible changes. This will be announced in the respective release notes and should be the exception.
4. SQL building
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
SQL is a declarative language that is hard to integrate into procedural, object-oriented, functional or any other type of programming languages. jOOQ's philosophy is to give SQL the credit it deserves and integrate SQL itself as an "internal domain specific language" directly into Java.
With this philosophy in mind, SQL building is the main feature of jOOQ. All other features (such as SQL execution and code generation) are mere convenience built on top of jOOQ's SQL building capabilities.
This section explains all about the various syntax elements involved with jOOQ's SQL building capabilities. For a complete overview of all syntax elements, please refer to the manual's sections about SQL to DSL mapping rules.
4.1. The query DSL type
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ exposes a lot of interfaces and hides most implementation facts from client code. The reasons for this are:
- Interface-driven design. This allows for modelling queries in a fluent API most efficiently
- Reduction of complexity for client code.
- API guarantee. You only depend on the exposed interfaces, not concrete (potentially dialect-specific) implementations.
The org.jooq.impl.DSL
class is the main class from where you will create all jOOQ objects. It serves as a static factory for table expressions, column expressions (or "fields"), conditional expressions and many other QueryParts.
The static query DSL API
With jOOQ 2.0, static factory methods have been introduced in order to make client code look more like SQL. Ideally, when working with jOOQ, you will simply static import all methods from the DSL class:
import static org.jooq.impl.DSL.*;
Note, that when working with Eclipse, you could also add the DSL to your favourites. This will allow to access functions even more fluently:
concat(trim(FIRST_NAME), trim(LAST_NAME)); // ... which is in fact the same as: DSL.concat(DSL.trim(FIRST_NAME), DSL.trim(LAST_NAME));
4.1.1. DSL subclasses
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
There are a couple of subclasses for the general query DSL. Each SQL dialect has its own dialect-specific DSL. For instance, if you're only using the MySQL dialect, you can choose to reference the MySQLDSL instead of the standard DSL:
The advantage of referencing a dialect-specific DSL lies in the fact that you have access to more proprietary RDMBS functionality. This may include:
- MySQL's encryption functions
- PL/SQL constructs, pgplsql, or any other dialect's ROUTINE-language (maybe in the future)
4.2. The DSLContext API
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
DSLContext references a org.jooq.Configuration
, an object that configures jOOQ's behaviour when executing queries (see SQL execution for more details). Unlike the static DSL, the DSLContext allow for creating SQL statements that are already "configured" and ready for execution.
Fluent creation of a DSLContext object
The DSLContext object can be created fluently from the DSL type:
// Create it from a pre-existing configuration DSLContext create = DSL.using(configuration); // Create it from ad-hoc arguments DSLContext create = DSL.using(connection, dialect);
If you do not have a reference to a pre-existing Configuration object (e.g. created from org.jooq.impl.DefaultConfiguration
), the various overloaded DSL.using()
methods will create one for you.
Contents of a Configuration object
A Configuration can be supplied with these objects:
-
org.jooq.SQLDialect
: The dialect of your database. This may be any of the currently supported database types (see SQL Dialect for more details) -
org.jooq.conf.Settings
: An optional runtime configuration (see Custom Settings for more details) -
org.jooq.ExecuteListenerProvider
: To provide execution lifecycle listeners (see ExecuteListeners for more details) -
org.jooq.ParseListenerProvider
: To provide custom parser extensions (see SQL Parser Listener for more details) -
org.jooq.RecordListenerProvider
: To provide record listeners for your CRUD operations (see CRUD SPI: RecordListener for more details) -
org.jooq.RecordMapperProvider
: To provide an alternative default record mapper implementation (see POJOs with RecordMappers for more details) -
org.jooq.FormattingProvider
: To provide custom default data export formats (see FormattingProvider for more details) - JDBC access:
-
java.sql.Connection
: An optional JDBC Connection that will be re-used for the whole lifecycle of your Configuration (see Connection vs. DataSource for more details). For simplicity, this is the use-case referenced from this manual, most of the time. -
java.sql.DataSource
: An optional JDBC DataSource that will be re-used for the whole lifecycle of your Configuration. If you prefer using DataSources over Connections, jOOQ will internally fetch new Connections from your DataSource, conveniently closing them again after query execution. This is particularly useful in Java EE or Spring contexts (see Connection vs. DataSource for more details) -
org.jooq.ConnectionProvider
: A custom abstraction that is used by jOOQ to "acquire" and "release" connections. jOOQ will internally "acquire" new Connections from your ConnectionProvider, conveniently "releasing" them again after query execution. (see Connection vs. DataSource for more details)
-
- R2DBC access:
-
io.r2dbc.spi.Connection
: An optional R2DBC Connection that will be re-used for the whole lifecycle of your Configuration (see Connection vs. DataSource for more details). For simplicity, this is the use-case referenced from this manual, most of the time. -
io.r2dbc.spi.ConnectionFactory
: An optional R2DBC ConnectionFactory that will be re-used for the whole lifecycle of your Configuration. If you prefer using ConnectionFactories over Connections, jOOQ will internally fetch new Connections from your ConnectionFactory, conveniently closing them again after query execution. This is particularly useful in Spring contexts (see Connection vs. DataSource for more details)
-
Usage of DSLContext
Wrapping a Configuration object, a DSLContext can construct statements, for later execution. An example is given here:
// The DSLContext is "configured" with a Connection and a SQLDialect DSLContext create = DSL.using(connection, dialect); // This select statement contains an internal reference to the DSLContext's Configuration: Select<?> select = create.selectOne(); // Using the internally referenced Configuration, the select statement can now be executed: Result<?> result = select.fetch();
Note that you do not need to keep a reference to a DSLContext. You may as well inline your local variable, and fluently execute a SQL statement as such:
// Execute a statement from a single execution chain: Result<?> result = DSL.using(connection, dialect) .select() .from(BOOK) .where(BOOK.TITLE.like("Animal%")) .fetch();
4.2.1. SQL Dialect
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
While jOOQ tries to represent the SQL standard as much as possible, many features are vendor-specific to a given database and to its "SQL dialect". jOOQ models this using the org.jooq.SQLDialect
enum type.
The SQL dialect is one of the main attributes of a Configuration. Queries created from DSLContexts will assume dialect-specific behaviour when rendering SQL and binding bind values.
Some parts of the jOOQ API are officially supported only by a given subset of the supported SQL dialects. For instance, the Oracle CONNECT BY clause, which is supported by the Oracle and Informix 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.INFORMIX, 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
- The CONNECT BY clause, for hierarchical queries
- The PIVOT keyword for creating PIVOT tables
- Packages, object-oriented user-defined types, member procedures as described in the section about stored procedures and functions
- Advanced analytical functions as described in the section about window functions
jOOQ has a historic affinity to Oracle's SQL extensions. If something is supported in Oracle SQL, it has a high probability of making it into the jOOQ API
4.2.2. SQL Dialect Family
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In jOOQ 3.1, the notion of a SQLDialect.family()
was introduced, in order to group several similar SQL dialects into a common family. An example for this is SQL Server, which is supported by jOOQ in various versions:
- SQL Server: The "version-less" SQL Server version. This always maps to the latest supported version of SQL Server
- SQL Server 2012: The SQL Server version 2012
- SQL Server 2008: The SQL Server version 2008
In the above list, SQLSERVER
is both a dialect and a family of three dialects. This distinction is used internally by jOOQ to distinguish whether to use the OFFSET .. FETCH clause (SQL Server 2012), or whether to emulate it using ROW_NUMBER() OVER()
(SQL Server 2008).
4.2.3. Connection vs. DataSource
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Interact with JDBC Connections
While you can use jOOQ for SQL building only, you can also run queries against a JDBC java.sql.Connection
. Internally, jOOQ creates java.sql.Statement
or java.sql.PreparedStatement
objects from such a Connection, in order to execute statements. The normal operation mode is to provide a Configuration with a JDBC Connection, whose lifecycle you will control yourself. This means that jOOQ will not actively close connections, rollback or commit transactions.
Note, in this case, jOOQ will internally use a org.jooq.impl.DefaultConnectionProvider
, which you can reference directly if you prefer that. The DefaultConnectionProvider exposes various transaction-control methods, such as commit(), rollback(), etc.
Interact with JDBC DataSources
If you're in a Java EE or Spring context, however, you may wish to use a javax.sql.DataSource
instead. Connections obtained from such a DataSource will be closed after query execution by jOOQ. The semantics of such a close operation should be the returning of the connection into a connection pool, not the actual closing of the underlying connection. Typically, this makes sense in an environment using distributed JTA transactions.
Note, in this case, jOOQ will internally use a org.jooq.impl.DataSourceConnectionProvider
, which you can reference directly if you prefer that.
Inject custom behaviour
If your specific environment works differently from any of the above approaches, you can inject your own custom implementation of a ConnectionProvider into jOOQ. This is the API contract you have to fulfil:
public interface ConnectionProvider { // Provide jOOQ with a connection Connection acquire() throws DataAccessException; // Get a connection back from jOOQ void release(Connection connection) throws DataAccessException; }
Reactive querying
If you wish to use an R2DBC driver, you do not have to supply a org.jooq.ConnectionProvider
to your Configuration. Instead, jOOQ can work with a io.r2dbc.spi.Connection
(jOOQ will never close it) or io.r2dbc.spi.ConnectionFactory
(jOOQ will close all R2DBC Connections that it creates).
4.2.4. Custom data
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In advanced use cases of integrating your application with jOOQ, you may want to put custom data into your Configuration, which you can then access from your...
Here is an example of how to use the custom data API. Let's assume that you have written an ExecuteListener, that prevents INSERT
statements, when a given flag is set to true
:
public class NoInsertListener implements ExecuteListener { @Override public void start(ExecuteContext ctx) { // This listener is active only, when your custom flag is set to true if (Boolean.TRUE.equals(ctx.configuration().data("com.example.my-namespace.no-inserts"))) { // If active, fail this execution, if an INSERT statement is being executed if (ctx.query() instanceof Insert) { throw new DataAccessException("No INSERT statements allowed"); } } } }
See the manual's section about ExecuteListeners to learn more about how to implement an ExecuteListener
.
Now, the above listener can be added to your Configuration, but you will also need to pass the flag to the Configuration
, in order for the listener to work:
// Create your Configuration Configuration configuration = new DefaultConfiguration().set(connection).set(dialect); // Set a new execute listener provider onto the configuration: configuration.set(new DefaultExecuteListenerProvider(new NoInsertListener())); // Use any String literal to identify your custom data configuration.data("com.example.my-namespace.no-inserts", true); // Try to execute an INSERT statement try { DSL.using(configuration) .insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME) .values(1, "Orwell") .execute(); // You shouldn't get here Assert.fail(); } // Your NoInsertListener should be throwing this exception here: catch (DataAccessException expected) { Assert.assertEquals("No INSERT statements allowed", expected.getMessage()); }
Using the data()
methods, you can store and retrieve custom data in your Configurations
.
4.2.5. Custom ExecuteListeners
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
ExecuteListeners
are a useful tool to...
- implement custom logging
- apply triggers written in Java
- collect query execution statistics
ExecuteListeners are hooked into your Configuration by returning them from an org.jooq.ExecuteListenerProvider
:
// Create your Configuration Configuration configuration = new DefaultConfiguration().set(connection).set(dialect); // Hook your listener providers into the configuration: configuration.set( new DefaultExecuteListenerProvider(new MyFirstListener()), new DefaultExecuteListenerProvider(new PerformanceLoggingListener()), new DefaultExecuteListenerProvider(new NoInsertListener()) );
See the manual's section about ExecuteListeners to see examples of such listener implementations.
4.2.6. Custom Unwrappers
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
JDBC knows the java.sql.Wrapper
API, which is implemented by all JDBC types in order to be able to "unwrap" a native driver implementation for any given type. For example:
// This may be some proxy from a connection pool Connection c = getConnection(); // Sometimes, we want the native driver connection instance OracleConnection oc = c.unwrap(OracleConnection.class); Array array = oc.createARRAY("ARRAY_TYPE", new Object[] { "a", "b" });
jOOQ internally makes similar calls occasionally. For this, it needs to unwrap the native java.sql.Connection
or java.sql.PreparedStatement
instance. Unfortunately, not all third party libraries correctly implement the Wrapper
API contract, so this unwrapping might not work. The org.jooq.Unwrapper
SPI is designed to allow for custom implementations to be injected into jOOQ configurations:
// Your jOOQ configuration Configuration c1 = getConfiguration(); Configuration c2 = c.derive(new Unwrapper() { @Override public <T> T unwrap(Wrapper wrapper, Class<T> iface) { try { if (wrapper instanceof Connection) // ... else if (wrapper instanceof Statement) // ... else wrapper.unwrap(iface); } catch (SQLException e) { // ... } } }); // Work with the derived configuration, where needed DSL.using(c2).fetch("...");
4.2.7. Custom Settings
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The jOOQ Configuration allows for some optional configuration elements to be used by advanced users. The org.jooq.conf.Settings
class is a JAXB-annotated type, that can be provided to a Configuration in several ways:
- In the DSLContext constructor (
DSL.using()
). This will override default settings below - in the
org.jooq.impl.DefaultConfiguration
constructor. This will override default settings below - From a location specified by a JVM parameter: -Dorg.jooq.settings
- From the classpath at /jooq-settings.xml
- From the settings defaults, as specified in https://www.jooq.org/xsd/jooq-runtime-3.17.0.xsd
The most specific settings for a given context will apply.
If you wish to configure your settings through XML, but explicitly load them for a given Configuration
, you can do so as well, using JAXB:
Settings settings = JAXB.unmarshal(new File("/path/to/settings.xml"), Settings.class);
Example
For example, if you want to indicate to jOOQ, that it should inline all bind variables, and execute static java.sql.Statement
instead of binding its variables to java.sql.PreparedStatement
, you can do so by creating the following DSLContext:
Settings settings = new Settings(); settings.setStatementType(StatementType.STATIC_STATEMENT); DSLContext create = DSL.using(connection, dialect, settings);
More details
Please refer to the jOOQ runtime configuration XSD for more details:
https://www.jooq.org/xsd/jooq-runtime-3.17.0.xsd
4.2.7.1. Auto-attach Records
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
By default, all records fetched through jOOQ are "attached" to the configuration that created them. This allows for features like updatable records as can be seen here:
AuthorRecord author = DSL.using(configuration) // This configuration will be attached to any record produced by the below query. .selectFrom(AUTHOR) .where(AUTHOR.ID.eq(1)) .fetchOne(); author.setLastName("Smith"); author.store(); // This store call operates on the "attached" configuration.
In some cases (e.g. when serialising records), it may be desirable not to attach the Configuration
that created a record to the record. This can be achieved with the attachRecords
setting:
Example configuration
Settings settings = new Settings() .withAttachRecords(false); // Defaults to true
4.2.7.2. Auto-inline bind values
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Bind values are an important concept in SQL, for performance reasons, as they simplify caching of prepared statements in some RDBMS. jOOQ always creates bind values by default, when you write this:
-- Normally, a bind parameter marker is generated AUTHOR.ID = ?
// This is the same as AUTHOR.ID.eq(val(1, AUTHOR.ID)) AUTHOR.ID.eq(1);
In some cases, however, it is better not to use a bind variable, but to create inline values, instead, so the optimiser can better apply its statistics. This is useful mainly when:
- The column is a constant discriminator column in a view, for example
- The column has very skewed statistics and only few possible values (e.g. a
BOOLEAN
, anENUM
type or aCHECK COL IN (1, 2, 3)
) constraint.
In those cases, it can be useful to enable Settings.transformInlineBindValuesForFieldComparisons and implement a org.jooq.TransformProvider
as follows:
Configuration configuration = ... configuration.settings().setTransformInlineBindValuesForFieldComparisons(true); configuration.set(new TransformProvider() { @Override public boolean inlineBindValuesForFieldComparisons(Field<?> field) { return field.getType() == Boolean.class || field.getDataType().isEnum(); // Or, perhaps, limit this only to certain enums } });
Now, all queries whose predicates match the above TransformProvider
content will have their relevant bind values inlined. For example:
-- Inlining applies to some columns now, not all AUTHOR.ID = ? AND AUTHOR.STATUS = 'ACTIVE'
AUTHOR.ID.eq(1).and( AUTHOR.STATUS.eq(Status.ACTIVE));
Related settings include:
4.2.7.3. Backslash Escaping
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some databases (mainly MySQL and MariaDB) unfortunately chose to go an alternative, non-SQL-standard route when escaping string literals. Here's an example of how to escape a string containing apostrophes in different dialects:
SELECT 'I''m sure this is OK' AS val -- Standard SQL escaping of apostrophe by doubling it. SELECT 'I\'m certain this causes trouble' AS val -- Vendor-specific escaping of apostrophe by using a backslash.
As most databases don't support backslash escaping (and MySQL also allows for turning it off!), jOOQ by default also doesn't support it when inlining bind variables. However, this can lead to SQL injection vulnerabilities and syntax errors when not dealing with it carefully!
This feature is turned on by default and for historic reasons for MySQL and MariaDB.
-
DEFAULT
(the - surprise! - default): Turns the featureON
for MySQL and MariaDB andOFF
for all other dialects -
ON
: Turn the feature on. -
OFF
: Turn the feature off.
Example configuration
Settings settings = new Settings() .withBackslashEscaping(BackslashEscaping.OFF); // Default to DEFAULT
4.2.7.4. Batch size
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ offers a transparent batching API, which can buffer all statements generated by jOOQ and other JDBC backed APIs transparently in order to batch them:
// Everything in the below lambda will be buffered and batched DSL.using(configuration).batched(c -> { module1.insertSomething(c); module2.insertSomethingElse(c); });
Use the Settings.batchSize
flag to govern the maximum batch statement size of this API:
Settings settings = new Settings() .withBatchSize(100); // Default Integer.MAX_VALUE
4.2.7.5. Execute Logging
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The executeLogging
setting turns off the default logging implemented through org.jooq.tools.LoggerListener
Example configuration
Settings settings = new Settings() .withExecuteLogging(false); // Defaults to true
4.2.7.6. Fetch Warnings
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Apart from JDBC exceptions, there is also the possibility to handle java.sql.SQLWarning
, which are made available to jOOQ users through the java.sql.ExecuteListener
SPI and the log
Users who do not wish to get these notifications (e.g. for performance reasons), may turn off fetching of warnings through the fetchWarnings
setting:
Example configuration
Settings settings = new Settings() .withFetchWarnings(false); // Defaults to true
4.2.7.7. GROUP_CONCAT Configuration
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The MySQL GROUP_CONCAT function suffers from a controversial design decision where results are truncated after a certain length, the @@group_concat_max_len
.
Whenever jOOQ generates a GROUP_CONCAT
function, by default, that MySQL system variable is increased to the maximum value for the scope of a single statement, e.g.
SET @T = @@GROUP_CONCAT_MAX_LEN; SET @@GROUP_CONCAT_MAX_LEN = 4294967295; SELECT GROUP_CONCAT(TITLE SEPARATOR ', ') FROM BOOK; SET @@GROUP_CONCAT_MAX_LEN = @T;
More details here. While this is a reasonable default behaviour (as opposed to the random truncation), it may occasionally be undesired, e.g. if statement batches (;
separated statements) aren't possible in a single JDBC statement. The feature can be turned off with
Example configuration
Settings settings = new Settings() .withRenderGroupConcatMaxLenSessionVariable(false); // Defaults to true
4.2.7.8. Identifier style
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
By default, jOOQ will always generate quoted names for all identifiers (even if this manual omits this for readability). For instance:
SELECT "TABLE"."COLUMN" FROM "TABLE" -- SQL standard style SELECT `TABLE`.`COLUMN` FROM `TABLE` -- MySQL style SELECT [TABLE].[COLUMN] FROM [TABLE] -- SQL Server style
Quoting has the following effect on identifiers in most (but not all) databases:
- It allows for using reserved names as object names, e.g. a table called
"FROM"
is usually possible only when quoted. - It allows for using special characters in object names, e.g. a column called
"FIRST NAME"
can be achieved only with quoting. - It turns what are mostly case-insensitive identifiers into case-sensitive ones, e.g.
"name"
and"NAME"
are different identifiers, whereasname
andNAME
are not. Please consider your database manual to learn what the proper default case and default case sensitivity is.
The renderQuotedNames
and renderNameCase
settings allow for overriding the name of all identifiers in jOOQ to a consistent style. Possible options are:
RenderQuotedNames
-
ALWAYS
: This will quote all identifiers. -
EXPLICIT_DEFAULT_QUOTED
: This will quote all identifiers, which are not explicitly unquoted using DSL.unquotedName(). -
EXPLICIT_DEFAULT_UNQUOTED
: This will not quote any identifiers, unless they are explicitly quoted using DSL.quotedName(). -
NEVER
: This will not quote any identifiers.
RenderNameCase
-
AS_IS
: This will generate all names in their proper case. -
LOWER
: This will transform all names to lower case. -
LOWER_IF_UNQUOTED
: This will transform all names to lower case if the name is unquoted. -
UPPER
: This will transform all names to upper case. -
UPPER_IF_UNQUOTED
: This will transform all names to upper case if the name is unquoted.
The two flags are independent of one another. If your database supports quoted, case sensitive identifiers, then using LOWER
or UPPER
on quoted identifiers may not work.
Example configuration
Settings settings = new Settings() .withRenderQuotedNames(RenderQuotedNames.EXPLICIT_DEFAULT_UNQUOTED) // Defaults to EXPLICIT_DEFAULT_QUOTED .withRenderNameCase(RenderNameCase.LOWER_IF_UNQUOTED); // Defaults to AS_IS
The behaviour of this setting is influenced by the renderLocale setting.
4.2.7.9. Implicit join type
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ's very useful implicit JOIN feature can be used to use a path notation to join tables on their actual, or synthetic foreign keys. For example:
// 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();
By default, this produces:
- An
INNER JOIN
if all columns of the foreign key areNOT NULL
- A
LEFT JOIN
if the foreign key is nullable / optional
This behaviour means that implicit joins do not filter results when placed in clauses that are not meant to filter, such as the SELECT clause or the ORDER BY clause.
Users may prefer to enforce a different behaviour, including:
- Always produce a
LEFT JOIN
, e.g. because this was the behaviour before jOOQ 3.14 - Always produce an
INNER JOIN
, e.g. because they're migrating off Hibernate / JPA, and depend on Hibernate's implicit joins producing inner joins
This change of behaviour can be achieved with the following setting:
Example configuration
Settings settings = new Settings() .withRenderImplicitJoinType(RenderImplicitJoinType.INNER_JOIN);
4.2.7.10. Inline Threshold
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Previous sections showed how the SQL generation of bind values can be controlled, e.g. by forcing them to be inlined, or by running a static JDBC statement.
Sometimes, inlining needs to be enforced dynamically, depending on the query content. This is the case when there are a great number of bind variables. Known vendor-specific limits are:
- Access : 768
- Ingres : 1024
- Oracle : 32767
- PostgreSQL : 32767
- SQLite : 999
- SQL Server : 2100
- Sybase ASE : 2000
By default, jOOQ will automatically inline all bind variables in any SQL statement, once these thresholds have been reached. However, it is possible to override this default and provide a setting to re-define a global threshold for all dialects.
Example configuration
Settings settings = new Settings() .withInlineThreshold(100); // Defaults to 0, which means the default thresholds are applied
4.2.7.11. IN-list Padding
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Databases that feature a cursor cache / statement cache (e.g. Oracle, SQL Server, DB2, etc.) are highly optimised for prepared statement re-use. When a client sends a prepared statement to the server, the server will go to the cache and look up whether there already exists a previously calculated execution plan for the statement (i.e. the SQL string). This is called a "soft-parse" (in Oracle). If not, the execution plan is calculated on the fly. This is called a "hard-parse" (in Oracle).
Preventing hard-parses is extremely important in high throughput OLTP systems where queries are usually not very complex but are run millions of times in a short amount of time. Using bind variables, this is usually not a problem, with the exception of the IN predicate, which generates different SQL strings even when using bind variables:
-- All of these are different SQL statements: SELECT * FROM AUTHOR WHERE ID IN (?) SELECT * FROM AUTHOR WHERE ID IN (?, ?) SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?) SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?) SELECT * FROM AUTHOR WHERE ID IN (?, ?, ?, ?, ?)
This problem may not be obvious to Java / jOOQ developers, as they are always produced from the same jOOQ statement:
// All of these are the same jOOQ statement DSL.using(configuration) .select() .from(AUTHOR) .where(AUTHOR.ID.in(collection)) .fetch();
Depending on the possible sizes of the collection, it may be worth exploring using arrays or temporary tables as a workaround, or to reuse the original query that produced the set of IDs in the first place (through a semi-join). But sometimes, this is not possible. In this case, users can opt in to a third workaround: enabling the inListPadding
setting. If enabled, jOOQ will "pad" the IN
list to a length that is a power of two (configurable with Settings.inListPadBase
). 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!
Example configuration
Settings settings = new Settings() .withInListPadding(true) // Default to false .withInListPadBase(4); // Default to 2
4.2.7.12. Interpreter Configuration
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL Interpreter API ships with a variety of settings that govern its behaviour. These settings include:
-
interpreterDialect
: The interpreter input dialect. This dialect is used to decide whether DDL interpretation should be done on an actual in-memory database of a specific type, or using jOOQ's built in DDL interpretation. -
interpreterDelayForeignKeyDeclarations
: Whether the interpreter should delay the application of foreign key declarations (in case of which forward references are possible). -
interpreterLocale
: The locale to use for things like case insensitive comparisons. -
interpreterNameLookupCaseSensitivity
: The identifier case sensitivity that should be applied when interpreting SQL, depending on whether identifiers are quoted or not. -
interpreterSearchPath
: The search path for unqualified schema objects used by the interpreter.
Example configuration
Settings settings = new Settings() .withInterpreterDialect(H2) // Defaults to DEFAULT .withInterpreterDelayForeignKeyDeclarations(true) // Defaults to false .withInterpreterLocale(Locale.forLanguageTag("de")) // Defaults to Locale.getDefault() .withInterpreterNameLookupCaseSensitivity(NEVER) // Defaults to WHEN_QUOTED .withInterpreterSearchPath(...); // Defaults to an empty list
4.2.7.13. JDBC Flags
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
JDBC statements feature a couple of flags that influence the execution of such a statement. Each of these flags can be configured through jOOQ's org.jooq.Query
and org.jooq.ResultQuery
on a statement-per-statement basis, but there's also the possibility to centrally specify a value for these flags. These are the three flags:
-
queryTimeout
: The JDBC statement timeout in seconds. Corresponds to Query.queryTimeout() or Statement.setQueryTimeout() -
maxRows
: The maximum number of rows returned by the JDBC statement. Corresponds to ResultQuery.maxRows() or Statement.setMaxRows() -
fetchSize
: The number of rows to be buffered by the JDBC ResultSet. Corresponds to ResultQuery.fetchSize() or Statement.setFetchSize()
All of these flags are JDBC-only features with no direct effect on jOOQ. jOOQ only passes them through to the underlying statement.
Example configuration
Settings settings = new Settings() .withQueryTimeout(5) .withQueryPoolable(DEFAULT) .withMaxRows(1000) .withFetchSize(20);
4.2.7.14. Keyword style
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In all SQL dialects, keywords are case insensitive, and this is also the default in jOOQ, which mostly generates lower-case keywords.
Users may wish to adapt this and they have these options for the renderKeywordCase
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.
Example configuration
Settings settings = new Settings() .withRenderKeywordCase(RenderKeywordCase.UPPER); // Defaults to AS_IS
4.2.7.15. Listener Invocation Order
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ offers a variety of SPIs in the Configuration object. Some of those SPIs are event listeners, that can listen to "start" and "end" events, such as for example the ExecuteListener that listens to the query execution lifecycle.
When registering multiple listeners of a type, the invocation order may be relevant as custom listeners might communicate with each other. In such a case, the following settings allow for overriding the invocation order of "start" and "end" events for each type of listener:
Example configuration
Settings settings = new Settings() .withTransactionListenerStartInvocationOrder(DEFAULT) // Defaults to DEFAULT .withTransactionListenerEndInvocationOrder(REVERSE) // Defaults to DEFAULT .withVisitListenerStartInvocationOrder(DEFAULT) // Defaults to DEFAULT .withVisitListenerEndInvocationOrder(REVERSE) // Defaults to DEFAULT .withRecordListenerStartInvocationOrder(DEFAULT) // Defaults to DEFAULT .withRecordListenerEndInvocationOrder(REVERSE) // Defaults to DEFAULT .withExecuteListenerStartInvocationOrder(DEFAULT) // Defaults to DEFAULT .withExecuteListenerEndInvocationOrder(REVERSE); // Defaults to DEFAULT
4.2.7.16. Locales
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When doing locale sensitive operations, such as upper casing or lower casing a name (see Name styles), then it may be important in some areas to be able to specify the java.util.Locale for the operation.
Example configuration
// All of these default to Locale.getDefault(), if not specified explicitly Settings settings = new Settings() .withLocale(Locale.forLanguageTag("de")) // The default locale if no more specific locales are specified .withRenderLocale(Locale.forLanguageTag("de")) // The locale used when rendering SQL .withParseLocale(Locale.forLanguageTag("de")) // The locale used when parsing SQL .withInterpreterLocale(Locale.forLanguageTag("de")); // The locale used when interpreting SQL
4.2.7.17. Map JPA Annotations
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The org.jooq.impl.DefaultRecordMapper
supports basic JPA mapping (mostly @Table
and @Column
annotations). Looking up these annotations costs a slight extra overhead (mostly taken care of through reflection caching). It can be turned off using the mapJPAAnnotations
setting:
Example configuration
Settings settings = new Settings() .withMapJPAAnnotations(false); // Defaults to true
4.2.7.18. Object qualification
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
By default, jOOQ fully qualifies all objects with their catalog and schema names, if such qualification is made available by the code generator. For instance, the following SQL statement containing full qualification may be produced by jOOQ code with seemingly no qualification:
-- Full qualification on columns and tables SELECT catalog.schema.table.column FROM catalog.schema.table
DSL.using(configuration) .select(TABLE.COLUMN) // Column only qualified with table .from(TABLE) // No qualification on table
While the jOOQ code is also implicitly fully qualified (see implied imports), it may not be desireable to use fully qualified object names in SQL. The renderCatalog
and renderSchema
settings are used for this.
Example configuration
new Settings() .withRenderCatalog(false) // Defaults to true .withRenderSchema(false); // Defaults to true
More sophisticated multitenancy approaches are available through the render mapping feature.
4.2.7.19. Optimistic Locking
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
There are two settings governing the behaviour of the jOOQ optimistic locking feature:
-
updateRecordVersion
: Whether UpdatableRecord instances should modify the record version prior to storing the record. This feature is independent of, but related to optimistic locking. -
updateRecordTimestamp
: Whether UpdatableRecord instances should modify the record timestamp prior to storing the record. This feature is independent of, but related to optimistic locking. -
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.
Example configuration
Settings settings = new Settings() .withUpdateRecordVersion(true) // Defaults to true .withUpdateRecordTimestamp(true) // Defaults to true .withExecuteWithOptimisticLocking(true) // Defaults to false .withExecuteWithOptimisticLockingExcludeUnversioned(false); // Defaults to false
For more details, please refer to the manual's section about the optimistic locking feature.
4.2.7.20. Parameter name prefix
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When choosing a ParameterType.NAMED to produce named parameters, the default is to use a colon as a prefix to the parameter name, for example:
-- NAMED SELECT FIRST_NAME || :1 FROM AUTHOR WHERE ID = :x
Depending on how the named parameters are interpreted, this default is not optimal. A better character might be the $
sign, e.g. in PostgreSQL or R2DBC. For this, the renderNamedParamPrefix
setting can be used:
Example configuration
Settings settings = new Settings() .withRenderNamedParamPrefix("$"); // Defaults to ":"
4.2.7.21. Parameter types
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Bind values or bind parameters come in different flavours in different SQL databases. JDBC standardises on their syntax by allowing only ?
(question mark) characters as placeholders for bind variables. Thus, jOOQ, by default, generates ?
placeholders for JDBC consumptions.
Users who wish to use jOOQ with a different backend than JDBC can specify that all jOOQ bind values, including indexed parameters and named parameters generate alternative strings, other than ?
. These are the current options:
-
INDEXED
(the default): Generates indexed parameter placeholders using?
. -
NAMED
: Generates named parameter placeholders, such as:param
for parameters that are named explicitly or:1
for unnamed, indexed parameters. -
NAMED_OR_INLINED:
Generates named parameter placeholders for parameters that are named explicitly and inlines all unnamed parameters. -
INLINED
: Inlines all parameters.
An example:
-- INDEXED SELECT FIRST_NAME || ? FROM AUTHOR WHERE ID = ? -- NAMED SELECT FIRST_NAME || :1 FROM AUTHOR WHERE ID = :x -- NAMED_OR_INLINED SELECT FIRST_NAME || 'x' FROM AUTHOR WHERE ID = :x -- INLINED SELECT FIRST_NAME || 'x' FROM AUTHOR WHERE ID = 42
Param<String> x = val("x"); Param<Integer> i = param("x", 42); DSL.using(configuration) .select(FIRST_NAME.concat(x)) .from(AUTHOR) .where(ID.eq(i)) .fetch();
Example configuration
Settings settings = new Settings() .withParamType(ParamType.NAMED); // Defaults to INDEXED
The following setting statementType may override this setting.
4.2.7.22. Parser Configuration
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL Parser API ships with a variety of settings that govern its behaviour. These settings include:
-
parseDialect
: The parser input dialect. This dialect is used to decide what vendor specific grammar should be applied in case of ambiguities that cannot be resolved from the context. -
parseDateFormat
: The date format that is applied automatically when parsing date formatting functions without an explicit format. -
parseIgnoreComments
: Using this flag, the parser can ignore certain sections that would otherwise be executed by RDBMS. Everything between anparseIgnoreCommentStart
and theparseIgnoreCommentStop
token will be ignored. -
parseIgnoreCommentStart
: The token that delimits the beginning of a section to be ignored by jOOQ. Ideally, this token is placed inside of a SQL comment. -
parseIgnoreCommentStop
: The token that delimits the end of a section to be ignored by jOOQ. Ideally, this token is placed inside of a SQL comment. -
parseRetainCommentsBetweenQueries
: Whether comments in between statements from Parser.parse() are retained and parsed as ignored queries. Comments inside of statements (including procedural statements) currently aren't supported by jOOQ. -
parseSearchPath
: The search path to look up unqualified identifiers to be used when usingparseWithMetaLookups
. Most dialects support a single schema on their search path (theCURRENT_SCHEMA
). PostgreSQL supports a'search_path'
, which allows for listing multiple schemata to use to look up unqualified tables, procedures, etc. in. -
parseTimestampFormat
: The timestamp format that is applied automatically when parsing timestamp formatting functions without an explicit format. -
parseUnsupportedSyntax
: The parser can parse some syntax that jOOQ does not support. By default, such syntax is ignored. Use this flag if you want to fail in such cases. -
parseUnknownFunctions
: The parser only parses "known" (to jOOQ) built in functions, and fails otherwise. This flag allows for parsing any built in function using a standardfunc_name(arg1, arg2, ...)
syntax. -
parseWithMetaLookups
: Whetherorg.jooq.Meta
should be used to look up meta information such as schemas, tables, columns, column types, etc.
An example of using the parseIgnoreComments
feature:
-- What you execute /* [jooq ignore start] */ CREATE SCHEMA s1; SET SCHEMA s1; /* [jooq ignore stop] */ /* [jooq ignore start] */ -- /* [jooq ignore stop] */ CREATE SCHEMA s2; /* [jooq ignore start] */ -- /* [jooq ignore stop] */ SET SCHEMA s2; CREATE TABLE t (i INTEGER);
-- What the jOOQ parser sees /* */ /* */ CREATE SCHEMA s2; /* */ SET SCHEMA s2; CREATE TABLE t (i INTEGER);
Example configuration
Settings settings = new Settings() .withParseDialect(SQLSERVER) // Defaults to DEFAULT .withParseWithMetaLookups(THROW_ON_FAILURE) // Defaults to OFF .withParseSearchPath( new ParseSearchSchemata().withSchema("PUBLIC"), new ParseSearchSchemata().withSchema("TEST")) .withParseUnsupportedSyntax(FAIL) // Defaults to IGNORE .withParseUnknownFunctions(IGNORE) // Defaults to FAIL .withParseIgnoreComments(true) // Defaults to false .withParseIgnoreCommentStart("<ignore>") // Defaults to "[jooq ignore start]" .withParseIgnoreCommentStop("</ignore>") // Defaults to "[jooq ignore stop]"
In addition to the above settings, there is also a powerful parser listener SPI called the org.jooq.ParseListener
.
4.2.7.23. Reflection caching
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
All operations of the DefaultRecordMapper are cached in the Configuration
by default for improved mapping and reflection speed. Users who prefer to override this cache, or work with their own custom record mapper provider may wish to turn off the out-of-the-box caching feature.
Example configuration
Settings settings = new Settings() .withReflectionCaching(false); // Defaults to true
4.2.7.24. Return all columns on store
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When using the updatable records feature, jOOQ always fetches the generated identity value, if such a value is available and if the return identity on store feature is enabled (it is, by default).
The identity value is not the only value that is generated by default. Specifically, there may be triggers that are used for auditing or other reasons, which generate LAST_UPDATE
or LAST_UPDATE_BY
values in a record. Users who wish to also automatically fetch these values after all store()
, insert()
, or update()
calls may do so by specifying the returnAllOnUpdatableRecord
setting. This setting depends on the availability of INSERT .. RETURNING, UPDATE .. RETURNING
, and DELETE .. RETURNING
statements, which are not available from all databases, in case of which a refresh()
call may be issued, creating a separate round trip to the server.
Example configuration
Settings settings = new Settings() .withReturnAllOnUpdatableRecord(true); // Defaults to false
4.2.7.25. Return Identity Value On Store
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When using the updatable records feature, jOOQ by default fetches the generated identity value.
In some situations, it is desirable for this feature to be turned off using the following flag:
Example configuration
Settings settings = new Settings() .withReturnIdentityOnUpdatableRecord(false); // Defaults to true
4.2.7.26. Runtime catalog, schema and table mapping
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Mapping your DEV schema to a productive environment
You may wish to design your database in a way that you have several instances of your schema. This is useful when you want to cleanly separate data belonging to several customers / organisation units / branches / users and put each of those entities' data in a separate database or schema.
In our AUTHOR example this would mean that you provide a book reference database to several companies, such as My Book World and Books R Us. In that case, you'll probably have a schema setup like this:
- DEV: Your development schema. This will be the schema that you base code generation upon, with jOOQ
- MY_BOOK_WORLD: The schema instance for My Book World
- BOOKS_R_US: The schema instance for Books R Us
Mapping DEV to MY_BOOK_WORLD with jOOQ
When a user from My Book World logs in, you want them to access the MY_BOOK_WORLD schema using classes generated from DEV. This can be achieved with the org.jooq.conf.RenderMapping
class, that you can equip your Configuration's settings with. Take the following example:
Example configuration
Settings settings = new Settings() .withRenderMapping(new RenderMapping() .withSchemata( new MappedSchema().withInput("DEV") .withOutput("MY_BOOK_WORLD"), new MappedSchema().withInput("LOG") .withOutput("MY_BOOK_WORLD_LOG")));
The query executed with a Configuration equipped with the above mapping will in fact produce this SQL statement:
SELECT * FROM MY_BOOK_WORLD.AUTHOR
DSL.using(connection, dialect, settings) .selectFrom(DEV.AUTHOR)
This works because AUTHOR
was generated from the DEV
schema, which is mapped to the MY_BOOK_WORLD
schema by the above settings.
Mapping of tables
Not only schemata can be mapped, but also tables. If you are not the owner of the database your application connects to, you might need to install your schema with some sort of prefix to every table. In our examples, this might mean that you will have to map DEV.AUTHOR to something MY_BOOK_WORLD.MY_APP__AUTHOR, where MY_APP__ is a prefix applied to all of your tables. This can be achieved by creating the following mapping:
Example configuration
Settings settings = new Settings() .withRenderMapping(new RenderMapping() .withSchemata( new MappedSchema().withInput("DEV") .withTables( new MappedTable().withInput("AUTHOR") .withOutput("MY_APP__AUTHOR"))));
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.
Mapping of catalogs
For databases like SQL Server, it is also possible to map catalogs in addition to schemata. The mechanism is exactly the same. So let's assume that we generated code for a table [dev].[dbo].[author] and want to map it to [my_book_world].[dbo].[author] at runtime. This can be achieved as follows:
Example configuration
Settings settings = new Settings() .withRenderMapping(new RenderMapping() .withCatalogs( new MappedCatalog().withInput("DEV") .withOutput("MY_BOOK_WORLD")));
To give you full control of how each and every table gets mapped, a MappedCatalog object can contain MappedSchema (and thus also MappedTable) definitions.
Using regular expressions
All of the above examples were using 1:1 constant name mappings where the input and output schema or table names are fixed by the configuration. With jOOQ 3.8, regular expression can be used as well for mapping, for example:
Example configuration
Settings settings = new Settings() .withRenderMapping(new RenderMapping() .withSchemata( new MappedSchema().withInputExpression(Pattern.compile("DEV_(.*)")) .withOutput("PROD_$1") .withTables( new MappedTable().withInputExpression(Pattern.compile("DEV_(.*)")) .withOutput("PROD_$1"))));
The only difference to the constant version is that the input
field is replaced by the inputExpression
field of type java.util.regex.Pattern
, in case of which the meaning of the output
field is a pattern replacement, not a constant replacement.
Hard-wiring mappings at code-generation time
Note that the manual's section about code generation schema mapping explains how you can hard-wire your catalog, schema and table mappings at code generation time.
Limitations
Mapped objects need to be known to the jOOQ org.jooq.RenderContext
, which means that for example plain SQL templates and their contents cannot be mapped. See also features requiring code generation for more details.
4.2.7.27. Scalar subqueries for stored functions
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This setting is useful mostly for the Oracle database, which implements a feature called scalar subquery caching, which is a good tool to avoid the expensive PL/SQL-to-SQL context switch when predicates make use of stored function calls.
With this setting in place, all stored function calls embedded in SQL statements will be wrapped in a scalar subquery:
SELECT (SELECT my_package.format(LANGUAGE_ID) FROM dual) FROM BOOK
DSL.using(configuration) .select(MyPackage.format(BOOK.LANGUAGE_ID)) .from(BOOK)
If our table contains thousands of books, but only a dozen of LANGUAGE_ID
values, then with scalar subquery caching, we can avoid most of the function calls and cache the result per LANGUAGE_ID
.
Example configuration
Settings settings = new Settings() .withRenderScalarSubqueriesForStoredFunctions(true);
4.2.7.28. Statement Type
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
JDBC knows two types of statements:
-
java.sql.PreparedStatement
: This allows for sending bind variables to the server. jOOQ uses prepared statements by default. -
java.sql.Statement
: Also "static statement". These do not support bind variables and may be useful for one-shot commands like DDL 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 theparamType == INLINED
. See parameter types
Example configuration
Settings settings = new Settings() .withStatementType(StatementType.STATIC_STATEMENT); // Defaults to PREPARED_STATEMENT
4.2.7.29. Updatable Primary Keys
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In most database design guidelines, primary key values are expected to never change - an assumption that is essential to a normalised database.
As always, there are exceptions to these rules, and users may wish to allow for updatable primary key values in the updatable records feature (note: any value can always be updated through ordinary update statements). An example:
AuthorRecord author = DSL.using(configuration) // This configuration will be attached to any record produced by the below query. .selectFrom(AUTHOR) .where(AUTHOR.ID.eq(1)) .fetchOne(); author.setId(2); author.store(); // The behaviour of this store call is governed by the updatablePrimaryKeys flag
The above store call depends on the value of the updatablePrimaryKeys
flag:
-
false
(the default): Since immutability of primary keys is assumed, the store call will create a new record (a copy) with the new primary key value. -
true
: Since mutablity of primary keys is allowed, the store call will change the primary key value from1
to2
.
Example configuration
Settings settings = new Settings() .withUpdatablePrimaryKeys(true); // Defaults to false
4.2.8. Thread safety
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
org.jooq.Configuration
, and by consequence org.jooq.DSLContext
, make no thread safety guarantees, but by carefully observing a few rules, they can be shared in a thread safe way. We encourage sharing Configuration
instances, because they contain caches for work not worth repeating, such as reflection field and method lookups for org.jooq.impl.DefaultRecordMapper
. If you're using Spring or CDI for dependency injection, you will want to be able to inject a DSLContext
instance everywhere you use it.
The following needs to be considered when attempting to share Configuration
and DSLContext
among threads:
-
Configuration
is mutable for historic reasons. Calls to variousConfiguration.set()
methods must be avoided after initialisation, should aConfiguration
(and by consequenceDSLContext
) instance be shared among threads. If you wish to modify some elements of aConfiguration
for single use, use theConfiguration.derive()
methods instead, which create a copy. -
Configuration
components, such asorg.jooq.conf.Settings
are mutable as well. The same rules for modification apply here. -
Configuration
allows for supplying user-defined SPI implementations (see above for examples). All of these must be thread safe as well, for their wrappingConfiguration
to be thread safe. If you are using aorg.jooq.impl.DataSourceConnectionProvider
, for instance, you must make sure that yourjavax.sql.DataSource
is thread safe as well. This is usually the case when you use a third party connection pool.
As can be seen above, Configuration
was designed to work in a thread safe way, despite it not making any such guarantee.
4.3. The DSL API
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DSL API is the primary way to construct queries or query parts in jOOQ. See the model API for an alternative way to interact with the jOOQ query object model.
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
Many other frameworks have similar APIs with similar feature sets. Yet, what makes jOOQ special is its informal BNF notation modelling a unified SQL dialect suitable for many vendor-specific dialects, and implementing that BNF notation as a hierarchy of interfaces in Java. This concept is extremely powerful, when using jOOQ with IDE syntax auto completion. Not only can you code much faster, your SQL code will be compile-checked to a certain extent. An example of a DSL query equivalent to the previous one is given here:
DSLContext create = DSL.using(connection, dialect); Result<?> result = create.select() .from(AUTHOR) .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
Unlike other, simpler frameworks that use "fluent APIs" or "method chaining", jOOQ's BNF-based interface hierarchy will not allow bad query syntax. The following will not compile, for instance:
DSLContext create = DSL.using(connection, dialect); Result<?> result = create.select() .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) // ^^^^ "join" is not possible here .from(AUTHOR) .fetch(); Result<?> result = create.select() .from(AUTHOR) .join(BOOK) .fetch(); // ^^^^^ "on" is missing here Result<?> result = create.select(rowNumber()) // ^^^^^^^^^ "over()" is missing here .from(AUTHOR) .fetch(); Result<?> result = create.select() .from(AUTHOR) .where(AUTHOR.ID.in(select(BOOK.TITLE).from(BOOK))) // ^^^^^^^^^^^^^^^^^^ // AUTHOR.ID is of type Field<Integer> but subselect returns Record1<String> .fetch(); Result<?> result = create.select() .from(AUTHOR) .where(AUTHOR.ID.in(select(BOOK.AUTHOR_ID, BOOK.ID).from(BOOK))) // ^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^ // AUTHOR.ID is of degree 1 but subselect returns Record2<Integer, Integer> .fetch();
4.3.1. Mutability (historic)
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For historic reasons, the DSL API mixes mutable and immutable behaviour with respect to the internal representation of the QueryPart being constructed. While creating conditional expressions, column expressions (such as functions) assumes immutable behaviour, creating SQL statements does not. In other words, the following can be said:
// Conditional expressions (immutable) // ----------------------------------- Condition a = BOOK.TITLE.eq("1984"); Condition b = BOOK.TITLE.eq("Animal Farm"); // The following can be said a != a.or(b); // or() does not modify a a.or(b) != a.or(b); // or() always creates new objects // Statements (mutable) // -------------------- SelectFromStep<?> s1 = select(); SelectJoinStep<?> s2 = s1.from(BOOK); SelectJoinStep<?> s3 = s1.from(AUTHOR); // The following can be said s1 == s2; // The internal object is always the same s2 == s3; // The internal object is always the same
On the other hand, beware that you can always extract and modify bind values from any QueryPart
.
4.4. The model API
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The model API is the secondary way to interact with queries or query parts in jOOQ. See the DSL API for the main way to interact with the jOOQ query object model.
4.4.1. Design
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This is experimental functionality, and as such subject to change. Use at your own risk!
The model API (Query Object Model or org.jooq.impl.QOM
) is an auxiliary API implemented by each and every org.jooq.QueryPart
allowing for users to get public access to jOOQ's internal query object model structure. For example:
// Create an expression using the DSL API: Field<String> field = substring(BOOK.TITLE, 2, 4); // Access the expression's internals using the model API if (field instanceof QOM.Substring substring) { Field<String> string = substring.$string(); Field<? extends Number> startingPosition = substring.$startingPosition(); Field<? extends Number> length = substring.$length(); }
Every argument passed to the DSL API has a $
prefixed accessor method on the model API, exposing the wrapped argument. Using these accessor methods, users can traverse the expression tree manually or via the model API traversal API. More recent Java language features like pattern matching can be very helpful for such operations, especially as we're planning to seal the entire query object model API.
All of the model API is immutable, but new expressions can still be created using equivalent $
prefixed setter methods, which don't mutate the original expression but return a copy:
// Produces a substring(BOOK.TITLE, 2, 4) column expression QOM.Substring substring = (QOM.Substring) substring(BOOK.TITLE, 2, 4); // Produces a substring(BOOK.TITLE, 3, 5) column expression substring.$startingPosition(val(3)).$length(val(5));
These basic operations allow for powerful SQL transformations on expression trees created with the DSL API but also with the SQL parser.
4.4.2. Traversal
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This is experimental functionality, and as such subject to change. Use at your own risk!
While the accessor methods from the model API allow for traversing the expression tree manually, a more generic way to traverse the expression tree is using the org.jooq.Traverser
API, which can traverse a org.jooq.QueryPart
in a similar fashion as a java.util.stream.Collector
can iterate a java.util.stream.Stream
, collecting and aggregating data about the expression tree. A Traverser consists of this API
:
public interface Traverser<A, R> { /** * A supplier for a temporary data structure to accumulate {@link QueryPart} * objects into during traversal. */ Supplier<A> supplier(); /** * An optional traversal abort condition to short circuit traversal e.g. * when the searched object has been found. */ Predicate<A> abort(); /** * An optional traversal abort condition to short circuit traversal e.g. * when the searched object has been found. */ Predicate<QueryPart> recurse(); /** * A callback that is invoked before recursing into a subtree. */ BiFunction<A, QueryPart, A> before(); /** * A callback that is invoked after recursing into a subtree. */ BiFunction<A, QueryPart, A> after(); /** * An optional transformation function to turn the temporary data structure * supplied by {@link #supplier()} into the final data structure. */ Function<A, R> finisher(); }
Some elements are similar to that of a java.util.stream.Collector
, others are specific to tree traversal.
A simple illustration shows what can be done:
// Any ordinary QueryPart: Condition condition = BOOK.ID.eq(1); int count = condition.$traverse( // Supplier of the initial data structure: an int () -> 0, // Print all traversed QueryParts and increment the counter (r, q) -> { System.out.println("Part " + r + ": " + q); return r + 1; } ); System.out.println("Count : " + count);
The above will print:
Part 0: "BOOK"."ID" = 1 Part 1: "BOOK"."ID" Part 2: 1 Count : 3
Using the same traverser on a slightly more complex QueryPart
Condition condition = BOOK.ID.eq(1).or(BOOK.ID.eq(2)); // ...
Part 0: ("BOOK"."ID" = 1 or "BOOK"."ID" = 2) Part 1: "BOOK"."ID" = 1 Part 2: "BOOK"."ID" Part 3: 1 Part 4: "BOOK"."ID" = 2 Part 5: "BOOK"."ID" Part 6: 2 Count : 7
Re-using your JDK collectors
Any Collector
can be turned into a Traverser
using Traversers.collecting(Collector). For example, if you want to count all QueryPart
items in an expression, instead of the above hand-written traverser, just use the JDK Collectors.counting():
// Contains 3 query parts long count1 = BOOK.ID.eq(1) .$traverse(Traversers.collecting(Collectors.counting()); // Contains 7 query parts long count2 = BOOK.ID.eq(1).or(BOOK.ID.eq(2)) .$traverse(Traversers.collecting(Collectors.counting());
Limitations
Just like model API replacement, traversers cannot traverse into "opaque" org.jooq.QueryPart
instances, including custom QueryParts or plain SQL templates. See also features requiring code generation for more details.
4.4.3. Replacement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This is experimental functionality, and as such subject to change. Use at your own risk!
A very powerful way to transform your SQL is to replace specific org.jooq.QueryPart
elements in any expression tree by something else using the QueryPart.replace() API. This API treats the expression tree as a persistent data structure, i.e. the resulting tree may consist of parts of the existing tree, but the existing tree is not modified.
Let's assume you wish to implement an optimisation engine that removes redundant SQL clauses. For example, an expression NOT(NOT(p))
can be replaced by p
in standard SQL (it may not be the exact same thing in some "clever" dialects without standard BOOLEAN
type support):
// Contains redundant operators Condition c = not(not(BOOK.ID.eq(1))); System.out.println(c); System.out.println(c.$replace(q -> q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Not n2 ? n2.$arg1() : q ));
The above prints:
not (not ("BOOK"."ID" = 1)) "BOOK"."ID" = 1
The replacement algorithm will attempt to run the replacement function recursively on your tree until it no longer affects the tree. This means two things:
- You can implement all of your replacement logic in a single function, for various rules. The order of application of the rules is the one you define in your function.
- The algorithm stops only when no more rules apply. If two rules turn
A > B
andB > A
, then the algorithm may never stop.
Here's a more complex example that logs the replacements with println()
calls:
// Contains redundant operators Condition c = not(not(not(BOOK.ID.ne(1)))); QueryPart result = c.$replace(q -> { if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Not n2) { System.out.println("Replacing NOT(NOT(p)) by NOT(p): " + q); return n2.$arg1(); } else if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Ne<?> n2) { System.out.println("Replacing NOT(x != y) by x = y: " + q); return n2.$arg1().eq((Field) n2.$arg2()); } return q; })); System.out.println("Result: " + result);
The output is:
Replacing NOT(x != y) by x = y: not ("BOOK"."ID" <> 1) Replacing NOT(NOT(p)) by NOT(p): not (not ("BOOK"."ID" = 1)) Result: "BOOK"."ID" = 1
As you can see:
- The replacement function is invoked several times.
- The second invocation can work on the result of the first invocation, where the
NOT (x != y)
predicate has already been improved. - The replacement works recursively, depth first, and bottom up.
- It stops when no more replacements take place.
This obviously also works when you use jOOQ's parser, and is extremely useful when used via the parsing connection, e.g. to optimise any type of JDBC or R2DBC based application!
// Contains redundant operators Condition c = create.parser().parseCondition("not not not book.id != 1"); QueryPart result = c.$replace(q -> { if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Not n2) { System.out.println("Replacing NOT(NOT(p)) by NOT(p): " + q); return n2.$arg1(); } else if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Ne<?> n2) { System.out.println("Replacing NOT(x != y) by x = y: " + q); return n2.$arg1().eq((Field) n2.$arg2()); } return q; })); System.out.println("Result: " + result);
The result is exactly the same:
Replacing NOT(x != y) by x = y: not (book.id <> 1) Replacing NOT(NOT(p)) by NOT(p): not (not (book.id = 1)) Result: book.id = 1
Starting from jOOQ 3.17, this logging can also be achieved using a listening replacer.
Built-in replacers
The following sections show a few examples of built-in replacers.
Limitations
Just like model API traversal, replacers cannot traverse into "opaque" org.jooq.QueryPart
instances, including custom QueryParts or plain SQL templates. See also features requiring code generation for more details.
4.4.3.1. Listening Replacer
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This is experimental functionality, and as such subject to change. Use at your own risk!
This replacer doesn't replace anything on its own, but helps debug things from other replacers. For example, a Replacer that removes redundant NOT(NOT(x))
expressions:
// The input condition Condition c = ctx.parser().parseCondition("not not not book.id != 1"); // The replacer doing the replacement Replacer r = Replacer.of(q -> { if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Not n2) return n2.$arg1(); else if (q instanceof QOM.Not n1 && n1.$arg1() instanceof QOM.Ne<?> n2) return n2.$arg1().eq((Field) n2.$arg2()); else return q; }); // A proxy to the above replacer, doing some logging r = Replacers.listening(r, (p1, p2) -> System.out.println("Replacing: " + p1 + " => " + p2)); // The application of the replacement QueryPart result = c.$replace(r); System.out.println("Result: " + result);
The above now prints each replacement that the depth first replacement algorithm applies to your expression tree, bottom-up:
Replacing: not (book.id <> 1) => book.id = 1 Replacing: not (not (book.id = 1)) => book.id = 1 Result: book.id = 1
4.4.3.2. Decomposing Replacer
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This is experimental functionality, and as such subject to change. Use at your own risk!
This replacer decomposes compound queries into their component queries. Some DDL statements are compound statements, such as e.g.
ALTER TABLE t ADD col1 INT, ADD col2 INT;
The above single compound statement can be decomposed into its component statements:
ALTER TABLE t ADD col1 INT; ALTER TABLE t ADD col2 INT;
Some use-cases, including DDL interpretation may be better served by component statements rather than the compound version.
As this org.jooq.Replacer
has to adhere to the contract imposed on replacers, it can only operate on org.jooq.Queries
and other org.jooq.Query
wrapping elements, such as org.jooq.Block
and other procedural scope statements.
4.4.4. The historic model API
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
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));
This API is completely mutable, and for historic reasons, early DSL API elements have inherited this mutability.
4.5. SQL Statements (DML)
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ currently supports 5 types of SQL statements. All of these statements are constructed from a DSLContext instance with an optional JDBC Connection or DataSource. If supplied with a Connection or DataSource, they can be executed. Depending on the query type, executed queries can return results.
4.5.1. The WITH clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL:1999 standard specifies the WITH
clause to be an optional clause for the SELECT statement, in order to specify common table expressions (also: CTE). Many other databases (such as PostgreSQL, SQL Server) also allow for using common table expressions also in other DML clauses, such as the INSERT statement, UPDATE statement, DELETE statement, or MERGE statement.
When using common table expressions with jOOQ, there are essentially two approaches:
- Declaring and assigning common table expressions explicitly to names
- Inlining common table expressions into a SELECT statement
Explicit common table expressions
The following example makes use of names to construct common table expressions, which can then be supplied to a WITH
clause or a FROM
clause of a SELECT statement:
-- Pseudo-SQL for a common table expression specification "t1" ("f1", "f2") AS (SELECT 1, 'a')
// Code for creating a CommonTableExpression instance name("t1").fields("f1", "f2").as(select(val(1), val("a")));
The above expression can be assigned to a variable in Java and then be used to create a full SELECT statement:
WITH "t1" ("f1", "f2") AS (SELECT 1, 'a'), "t2" ("f3", "f4") AS (SELECT 2, 'b') SELECT "t1"."f1" + "t2"."f3" AS "add", "t1"."f2" || "t2"."f4" AS "concat" FROM "t1", "t2" ;
CommonTableExpression<Record2<Integer, String>> t1 = name("t1").fields("f1", "f2").as(select(val(1), val("a"))); CommonTableExpression<Record2<Integer, String>> t2 = name("t2").fields("f3", "f4").as(select(val(2), val("b"))); Result<?> result2 = create.with(t1) .with(t2) .select( t1.field("f1").add(t2.field("f3")).as("add"), t1.field("f2").concat(t2.field("f4")).as("concat")) .from(t1, t2) .fetch();
Note that the org.jooq.CommonTableExpression
type extends the commonly used org.jooq.Table
type, and can thus be used wherever a table can be used.
Inlined common table expressions
If you're just operating on plain SQL, you may not need to keep intermediate references to such common table expressions. An example of such usage would be this:
WITH "a" AS (SELECT 1 AS "x", 'a' AS "y" ) SELECT FROM "a" ;
create.with("a").as(select( val(1).as("x"), val("a").as("y") )) .select() .from(table(name("a"))) .fetch();
4.5.2. The WITH RECURSIVE clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The various SQL dialects do not agree on the use of RECURSIVE
when writing recursive common table expressions. When using jOOQ, always use the DSLContext.withRecursive() or DSL.withRecursive() methods, and jOOQ will render the RECURSIVE
keyword, if needed.
Assuming a table like this:
CREATE TABLE directory ( id INT NOT NULL, parent_id INT, -- In PostgreSQL, use TEXT instead, to work around https://github.com/jOOQ/jOOQ/issues/12067 label VARCHAR(50), CONSTRAINT pk_directory PRIMARY KEY (id), CONSTRAINT fk_directory FOREIGN KEY (parent_id) REFERENCES directory (id) ); INSERT INTO directory VALUES ( 1, null, 'C:'); INSERT INTO directory VALUES ( 2, 1, 'eclipse'); INSERT INTO directory VALUES ( 3, 2, 'configuration'); INSERT INTO directory VALUES ( 4, 2, 'dropins'); INSERT INTO directory VALUES ( 5, 2, 'features'); INSERT INTO directory VALUES ( 7, 2, 'plugins'); INSERT INTO directory VALUES ( 8, 2, 'readme'); INSERT INTO directory VALUES ( 9, 8, 'readme_eclipse.html'); INSERT INTO directory VALUES (10, 2, 'src'); INSERT INTO directory VALUES (11, 2, 'eclipse.exe');
Using WITH RECURSIVE
, you can now query the structure of this directory as follows:
WITH RECURSIVE t ( id, name, path ) AS ( SELECT DIRECTORY.ID, DIRECTORY.LABEL, DIRECTORY.LABEL FROM DIRECTORY WHERE DIRECTORY.PARENT_ID IS NULL UNION ALL SELECT DIRECTORY.ID, DIRECTORY.LABEL, t.path || '\' || DIRECTORY.LABEL FROM t JOIN DIRECTORY ON t.id = DIRECTORY.PARENT_ID ) SELECT * FROM t;
CommonTableExpression<?> cte = name("t").fields( "id", "name", "path" ).as( select( DIRECTORY.ID, DIRECTORY.LABEL, DIRECTORY.LABEL) .from(DIRECTORY) .where(DIRECTORY.PARENT_ID.isNull()) .unionAll( select( DIRECTORY.ID, DIRECTORY.LABEL, field(name("t", "path"), VARCHAR) .concat("\\") .concat(DIRECTORY.LABEL)) .from(table(name("t"))) .join(DIRECTORY) .on(field(name("t", "id"), INTEGER) .eq(DIRECTORY.PARENT_ID))) ); System.out.println( create.withRecursive(cte) .selectFrom(cte) .fetch() );
The output would look like this:
+----+---------------------+---------------------------------------+ | id | name | path | +----+---------------------+---------------------------------------+ | 1 | C: | C: | | 2 | eclipse | C:\eclipse | | 3 | configuration | C:\eclipse\configuration | | 4 | dropins | C:\eclipse\dropins | | 11 | eclipse.exe | C:\eclipse\eclipse.exe | | 5 | features | C:\eclipse\features | | 7 | plugins | C:\eclipse\plugins | | 8 | readme | C:\eclipse\readme | | 9 | readme_eclipse.html | C:\eclipse\readme\readme_eclipse.html | | 10 | src | C:\eclipse\src | +----+---------------------+---------------------------------------+
Caveats
The SQL language expresses the recursion syntactically, meaning the table t
in the above example is being referenced from within the declaration of t
. This isn't possible in a language like Java. Hence, we must use the identifier API to construct identifier references for tables and columns. This technique usually appears a bit more verbose than ordinary jOOQ API usage that is based on generated code for your schema.
4.5.3. The SELECT statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When you don't just perform CRUD (i.e. SELECT * FROM your_table WHERE ID = ?), you're usually generating new record types using custom projections. With jOOQ, this is as intuitive, as if using SQL directly. A more or less complete example of the "standard" SQL syntax, plus some extensions, is provided by a query like this:
SELECT from a complex table expression
-- get all authors' first and last names, and the number -- of books they've written in German, if they have written -- more than five books in German in the last three years -- (from 2011), and sort those authors by last names -- limiting results to the second and third row, locking -- the rows for a subsequent update... whew! SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, COUNT(*) FROM AUTHOR JOIN BOOK ON AUTHOR.ID = BOOK.AUTHOR_ID WHERE BOOK.LANGUAGE = 'DE' AND BOOK.PUBLISHED_IN > 2008 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_IN.gt(2008)) .groupBy(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .having(count().gt(5)) .orderBy(AUTHOR.LAST_NAME.asc().nullsFirst()) .limit(2) .offset(1) .forUpdate() .fetch();
Details about the various clauses of this query will be provided in subsequent sections.
SELECT from single tables
A very similar, but limited API is available, if you want to select from single tables in order to retrieve TableRecords or even UpdatableRecords. The decision, which type of select to create is already made at the very first step, when you create the SELECT
statement with the DSL or DSLContext types:
public <R extends Record> SelectWhereStep<R> selectFrom(Table<R> table);
As you can see, there is no way to further restrict/project the selected fields. This just selects all known TableFields in the supplied Table, and it also binds <R extends Record> to your Table's associated Record. An example of such a Query would then be:
BookRecord book = create.selectFrom(BOOK) .where(BOOK.LANGUAGE.eq("DE")) .orderBy(BOOK.TITLE) .fetchAny();
The "reduced" SELECT API is limited in the way that it skips DSL access to any of these clauses:
In most parts of this manual, it is assumed that you do not use the "reduced" SELECT API. For more information about the simple SELECT API, see the manual's section about fetching strongly or weakly typed records.
4.5.3.1. SELECT clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SELECT
clause lets you project your own record types, referencing table fields, functions, arithmetic expressions, etc. The DSL type provides several methods for expressing a SELECT clause:
-- The SELECT clause SELECT BOOK.ID, BOOK.TITLE SELECT BOOK.ID, TRIM(BOOK.TITLE)
// Provide a varargs Fields list to the SELECT clause: Select<?> s1 = create.select(BOOK.ID, BOOK.TITLE); Select<?> s2 = create.select(BOOK.ID, trim(BOOK.TITLE));
The following sections illustrate various features and subclauses of the SELECT
clause.
4.5.3.1.1. Projection type safety
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Since jOOQ 3.0, records and row value expressions up to degree 22 are now generically typesafe. This is reflected by an overloaded SELECT
(and SELECT DISTINCT
) API in both DSL and DSLContext. An extract from the DSL type:
// Non-typesafe select methods: public static SelectSelectStep<Record> select(Collection<? extends SelectField<?>> fields); public static SelectSelectStep<Record> select(SelectField<?>... fields); // Typesafe select methods: public static <T1> SelectSelectStep<Record1<T1>> select(SelectField<T1> field1); public static <T1, T2> SelectSelectStep<Record2<T1, T2>> select(SelectField<T1> field1, SelectField<T2> field2); // [...]
The type that is being projected is the org.jooq.SelectField
, see also the next section about SelectField. Since the generic R type is bound to some Record[N], the associated T type information can be used in various other contexts, e.g. the IN predicate. Such a SELECT
statement can be assigned typesafely:
Select<Record2<Integer, String>> s1 = create.select(BOOK.ID, BOOK.TITLE); Select<Record2<Integer, String>> s2 = create.select(BOOK.ID, trim(BOOK.TITLE)); // Alternatively, just use var to infer the type: var s3 = create.select(BOOK.ID, trim(BOOK.TITLE));
For more information about typesafe record types with degree up to 22, see the manual's section about Record1 to Record22.
4.5.3.1.2. SelectField
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The org.jooq.SelectField
type is used by any projection of the SELECT clause and the INSERT .. RETURNING clause. It has numerous subtypes, which are allowed as projections in jOOQ:
-
org.jooq.Field
: Every column expression can automatically be projected inSELECT
as you would expect. -
org.jooq.Row
: nested records can be projected inSELECT
-
org.jooq.Table
: tables can be projected as type safe nested records inSELECT
- MULTISET and other means of projecting nested collections can be projected as well
4.5.3.1.3. Tables as SelectField
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
An org.jooq.Table
expression extends the org.jooq.SelectField
type, and as such, can be used in the SELECT clause directly, as well as everywhere else a SelectField
is accepted, e.g. in nested records. This is specifically useful for (generated) table references. The following shows how to project a nested org.jooq.TableRecord
:
Result<Record2<AuthorRecord, BookRecord>> result = create.select(AUTHOR, BOOK) .from(AUTHOR) .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .fetch();
This plays very well together with implicit joins:
Result<Record2<AuthorRecord, BookRecord>> result = create.select(BOOK.author(), BOOK) .from(BOOK) .fetch();
Behind the scenes, the implementation may either be native in dialects that support this kind of projection (e.g. PostgreSQL), or emulated using the usual nested records emulations.
4.5.3.1.4. SELECT *
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
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.
Whenever jOOQ generates an asterisk (explicitly, or because jOOQ doesn't know the exact projection), the column order, and the column set are defined by the database server, not jOOQ. If you're using generated code, this may lead to problems as there might be a different column order than expected, as well as too many or too few columns might be projected.
// 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.
4.5.3.1.5. SELECT * EXCEPT (...)
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A useful extension to the previously mentioned standard SQL SELECT * syntax is the BigQuery inspired * EXCEPT (columns)
syntax, which takes all of a projection's columns, except some columns. Just like the asterisk itself, this is mainly useful for ad-hoc querying, but it can also be useful for an occasional jOOQ query.
// Renders a SELECT * statement - Explicit unqualified asterisk create.select(asterisk().except(BOOK.ID)).from(BOOK).fetch(); // Renders a SELECT BOOK.* statement - Explicit qualified asterisk create.select(BOOK.asterisk().except(BOOK.ID)) .from(BOOK) .fetch(); create.select(BOOK.asterisk().except(BOOK.ID), AUTHOR.asterisk().except(AUTHOR.ID)) .from(BOOK, AUTHOR) .fetch();
If a dialect doesn't support this syntax natively, jOOQ will just expand the syntax for you, explicitly, given the knowledge about meta data in generated code.
Dialect support
This example using jOOQ:
select(asterisk().except(LANGUAGE.ID)).from(LANGUAGE)
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, -- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, -- VERTICA, YUGABYTEDB SELECT LANGUAGE.CD, LANGUAGE.DESCRIPTION FROM LANGUAGE -- BIGQUERY SELECT * EXCEPT (ID) FROM LANGUAGE -- H2 SELECT * EXCEPT (LANGUAGE.ID) FROM LANGUAGE -- SNOWFLAKE SELECT * EXCLUDE (ID) FROM LANGUAGE
4.5.3.1.6. SELECT DISTINCT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DISTINCT
keyword can be included in the method name, when constructing a SELECT
clause, to remove duplicate tuples from the projection.
SELECT DISTINCT BOOK.TITLE FROM BOOK
Select<?> select1 = create.selectDistinct(BOOK.TITLE).from(BOOK).fetch();
Dialect support
This example using jOOQ:
selectDistinct(BOOK.TITLE).from(BOOK)
Translates to the following dialect specific expressions:
-- All dialects SELECT DISTINCT BOOK.TITLE FROM BOOK
4.5.3.1.7. SELECT DISTINCT ON
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A useful, though perhaps a bit esoteric PostgreSQL specific extension to SELECT DISTINCT
is the ON
clause. Using this clause, PostgreSQL users can specify a distinctness criteria, but then produce other columns per distinct group from one of the group's tuples. This is normally not possible in SQL, but with ON
, the first tuple in the group according to the ORDER BY
clause can be accessed nonetheless. An example:
SELECT DISTINCT ON (BOOK.LANGUAGE_ID) BOOK.LANGUAGE_ID, BOOK.TITLE FROM BOOK ORDER BY BOOK.LANGUAGE_ID, BOOK.TITLE
Select<?> select1 = create.select(BOOK.LANGUAGE_ID, BOOK.TITLE) .distinctOn(BOOK.LANGUAGE_ID) .from(BOOK) .orderBy(BOOK.LANGUAGE_ID, BOOK.TITLE).fetch();
For syntactic reasons, the order of keywords had to be inversed as the PostgreSQL syntax cannot be easily reproduced in jOOQ's internal DSL. Quite likely, you might find jOOQ's syntax a bit more intuitive, though, as it more clearly separates the SELECT
parts and the DISTINCT ON
parts. Arguably, the DISTINCT ON
clause should be positioned after ORDER BY
, where it logically belongs.
Standard SQL equivalence
The PostgreSQL extension isn't really necessary as there is a standard SQL equivalence using ROW_NUMBER
filtering. In the below example, we're using an extension to the standard, the QUALIFY clause, to illustrate:
SELECT BOOK.LANGUAGE_ID, BOOK.TITLE FROM BOOK QUALIFY ROW_NUMBER() OVER (PARTITION BY BOOK.LANGUAGE_ID ORDER BY BOOK.TITLE) = 1 ORDER BY BOOK.LANGUAGE_ID, BOOK.TITLE
Select<?> select1 = create.select(BOOK.LANGUAGE_ID, BOOK.TITLE) .from(BOOK) .qualify(rowNumber().over(partitionBy(BOOK.LANGUAGE_ID).orderBy(BOOK.TITLE)).eq(1)) .orderBy(BOOK.LANGUAGE_ID, BOOK.TITLE).fetch();
Dialect support
This example using jOOQ:
select(BOOK.LANGUAGE_ID, BOOK.TITLE).distinctOn(BOOK.LANGUAGE_ID).from(BOOK).orderBy(BOOK.LANGUAGE_ID, BOOK.TITLE)
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, POSTGRES, YUGABYTEDB SELECT DISTINCT ON (BOOK.LANGUAGE_ID) BOOK.LANGUAGE_ID, BOOK.TITLE FROM BOOK ORDER BY BOOK.LANGUAGE_ID, BOOK.TITLE -- DB2, EXASOL, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, -- SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA SELECT t.LANGUAGE_ID, t.TITLE FROM ( SELECT BOOK.LANGUAGE_ID, BOOK.TITLE, row_number() OVER ( PARTITION BY BOOK.LANGUAGE_ID ORDER BY BOOK.LANGUAGE_ID, BOOK.TITLE ) rn FROM BOOK ) t WHERE rn = 1 ORDER BY LANGUAGE_ID, TITLE -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, HSQLDB /* UNSUPPORTED */
4.5.3.1.8. Convenience methods
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some commonly used projections can be easily created using convenience methods:
-- Simple SELECTs SELECT COUNT(*) SELECT 0 -- Not a bind variable SELECT 1 -- Not a bind variable
// Select commonly used values Result<?> result1 = create.selectCount().fetch(); Result<?> result2 = create.selectZero().fetch(); Result<?> result3 = create.selectOne().fetch();
Which are short forms for creating Column expressions from the org.jooq.impl.DSL
API
-- Simple SELECTs SELECT COUNT(*) SELECT 0 -- Not a bind variable SELECT ? -- A bind variable
// Select commonly used values Result<?> result1 = create.select(count()).fetch(); Result<?> result2 = create.select(inline(0)).fetch(); Result<?> result3 = create.select(val(1)).fetch();
4.5.3.2. FROM clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL FROM clause allows for specifying any number of table expressions to select data from. The following are examples of how to form normal FROM clauses:
SELECT 1 FROM BOOK SELECT 1 FROM BOOK, AUTHOR SELECT 1 FROM BOOK "b", AUTHOR "a"
create.selectOne().from(BOOK).fetch(); create.selectOne().from(BOOK, AUTHOR).fetch(); create.selectOne().from(BOOK.as("b"), AUTHOR.as("a")).fetch();
Read more about aliasing in the manual's section about aliased tables.
More advanced table expressions
Apart from simple tables, you can pass any arbitrary table expression to the jOOQ FROM clause. This may include unnested cursors in Oracle:
SELECT * FROM TABLE( DBMS_XPLAN.DISPLAY_CURSOR(null, null, 'ALLSTATS') );
create.select() .from(table( DbmsXplan.displayCursor(null, null, "ALLSTATS") ).fetch();
Note, in order to access the DbmsXplan package, you can use the code generator to generate Oracle's SYS schema.
Selecting FROM DUAL with jOOQ
In many SQL dialects, FROM is a mandatory clause, in some it isn't. jOOQ allows you to omit the FROM clause, returning just one record. An example:
SELECT 1 FROM DUAL SELECT 1
DSL.using(SQLDialect.ORACLE).selectOne().fetch(); DSL.using(SQLDialect.POSTGRES).selectOne().fetch();
Read more about dual or dummy tables in the manual's section about the DUAL table. The following are examples of how to form normal FROM clauses:
4.5.3.3. JOIN operator
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
jOOQ supports many different types of standard and non-standard SQL JOIN operations. All of these JOIN methods can be called on org.jooq.Table
types the (more info in joined tables section), or directly after the FROM clause for convenience. The following example joins AUTHOR and BOOK
DSLContext create = DSL.using(connection, dialect); // Call "join" directly on the AUTHOR table Result<?> result = create.select() .from(AUTHOR.join(BOOK) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))) .fetch(); // Call "join" on the type returned by "from" Result<?> result = create.select() .from(AUTHOR) .join(BOOK) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The two syntaxes will produce the same SQL statement. However, calling "join" on org.jooq.Table
objects allows for more powerful, nested JOIN expressions (if you can handle the parentheses):
SELECT * FROM AUTHOR LEFT OUTER JOIN ( BOOK JOIN BOOK_TO_BOOK_STORE ON BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID ) ON BOOK.AUTHOR_ID = AUTHOR.ID
// Nest joins and provide JOIN conditions only at the end create.select() .from(AUTHOR .leftOuterJoin(BOOK .join(BOOK_TO_BOOK_STORE) .on(BOOK_TO_BOOK_STORE.BOOK_ID.eq(BOOK.ID))) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))) .fetch();
- See the section about conditional expressions to learn more about the many ways to create
org.jooq.Condition
objects in jOOQ. - See the section about table expressions to learn about the various ways of referencing
org.jooq.Table
objects in jOOQ
For more information about the different types of join, please refer to the joined tables section.
4.5.3.4. Implicit path JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
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 b 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, and from jOOQ 3.19 also for to-many 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.
Default JOIN type
The default type of join that is generated is:
-
INNER JOIN
forto-one
path segments with non-nullable parent -
LEFT JOIN
forto-one
path segments with nullable parent
These defaults can be overridden with Settings.renderImplicitJoinType
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 JOIN
ed to the path's "root table". If two paths share a common prefix, that prefix is also shared in the join graph.
Known limitations
- 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
4.5.3.5. WHERE clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The WHERE clause can be used for JOIN or filter predicates, in order to restrict the data returned by the table expressions supplied to the previously specified from clause and join clause. Here is an example:
SELECT * FROM BOOK WHERE AUTHOR_ID = 1 AND TITLE = '1984'
create.select() .from(BOOK) .where(BOOK.AUTHOR_ID.eq(1)) .and(BOOK.TITLE.eq("1984")) .fetch();
The above syntax is convenience provided by jOOQ, allowing you to connect the org.jooq.Condition
supplied in the WHERE clause with another condition using an AND operator. You can of course also create a more complex condition and supply that to the WHERE clause directly (observe the different placing of parentheses). The results will be the same:
SELECT * FROM BOOK WHERE AUTHOR_ID = 1 AND TITLE = '1984'
create.select() .from(BOOK) .where(BOOK.AUTHOR_ID.eq(1).and( BOOK.TITLE.eq("1984"))) .fetch();
You will find more information about creating conditional expressions later in the manual.
4.5.3.6. CONNECT BY clause
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The Oracle database knows a very succinct syntax for creating hierarchical queries: the CONNECT BY clause, which is fully supported by jOOQ, including all related functions and pseudo-columns. A more or less formal definition of this clause is given here:
-- SELECT .. -- FROM .. -- WHERE .. CONNECT BY [ NOCYCLE ] condition [ AND condition, ... ] [ START WITH condition ] -- GROUP BY .. -- ORDER [ SIBLINGS ] BY ..
An example for an iterative query, iterating through values between 1 and 5 is this:
SELECT LEVEL FROM DUAL CONNECT BY LEVEL <= 5
// Get a table with elements 1, 2, 3, 4, 5 create.select(level()) .connectBy(level().le(5)) .fetch();
Here's a more complex example where you can recursively fetch directories in your database, and concatenate them to a path:
SELECT SUBSTR(SYS_CONNECT_BY_PATH(DIRECTORY.NAME, '/'), 2) FROM DIRECTORY CONNECT BY PRIOR DIRECTORY.ID = DIRECTORY.PARENT_ID START WITH DIRECTORY.PARENT_ID IS NULL ORDER BY 1
.select( substring(sysConnectByPath(DIRECTORY.NAME, "/"), 2)) .from(DIRECTORY) .connectBy( prior(DIRECTORY.ID).eq(DIRECTORY.PARENT_ID)) .startWith(DIRECTORY.PARENT_ID.isNull()) .orderBy(1) .fetch();
The output might then look like this
+------------------------------------------------+ |substring | +------------------------------------------------+ |C: | |C:/eclipse | |C:/eclipse/configuration | |C:/eclipse/dropins | |C:/eclipse/eclipse.exe | +------------------------------------------------+ |...21 record(s) truncated...
Some of the supported functions and pseudo-columns are these (available from the DSL):
- LEVEL
- CONNECT_BY_IS_CYCLE
- CONNECT_BY_IS_LEAF
- CONNECT_BY_ROOT
- SYS_CONNECT_BY_PATH
- PRIOR
ORDER SIBLINGS
The Oracle database allows for specifying a SIBLINGS keyword in the ORDER BY clause. Instead of ordering the overall result, this will only order siblings among each other, keeping the hierarchy intact. An example is given here:
SELECT DIRECTORY.NAME FROM DIRECTORY CONNECT BY PRIOR DIRECTORY.ID = DIRECTORY.PARENT_ID START WITH DIRECTORY.PARENT_ID IS NULL ORDER SIBLINGS BY 1
.select(DIRECTORY.NAME) .from(DIRECTORY) .connectBy( prior(DIRECTORY.ID).eq(DIRECTORY.PARENT_ID)) .startWith(DIRECTORY.PARENT_ID.isNull()) .orderSiblingsBy(1) .fetch();
4.5.3.7. GROUP BY clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
GROUP BY
can be used to create unique groups of data, to form aggregations, to remove duplicates and for other reasons. It will transform your previously defined set of table expressions, and return only one record per unique group as specified in this clause.
4.5.3.7.1. GROUP BY columns
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The GROUP BY
columns list specifies the columns whose values are used to form groups. The group columns can then be projected, whereas all the non-group columns can be aggregated. An example of such a grouped aggregation is this query:
SELECT AUTHOR_ID, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID
create.select(BOOK.AUTHOR_ID, count()) .from(BOOK) .groupBy(BOOK.AUTHOR_ID) .fetch();
The above example counts all books per author.
Note: a different and more powerful way of grouping data is to use the WINDOW clause and window functions.
Dialect support
This example using jOOQ:
select(BOOK.AUTHOR_ID, count()).from(BOOK).groupBy(BOOK.AUTHOR_ID)
Translates to the following dialect specific expressions:
-- All dialects SELECT BOOK.AUTHOR_ID, count(*) FROM BOOK GROUP BY BOOK.AUTHOR_ID
4.5.3.7.2. GROUP BY tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
An org.jooq.Table
expression extends the org.jooq.GroupField
type, and as such, can be used in the GROUP BY clause directly. This is specifically useful for (generated) table references. The following two statements are equivalent, although their generated SQL may differ, depending on native support:
// Ordinary grouping create.select(AUTHOR.ID, count()) .from(AUTHOR) .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .groupBy(AUTHOR) .fetch(); // Convenient grouping by the entire table create.select(AUTHOR.ID, count()) .from(AUTHOR) .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .groupBy(AUTHOR.ID) .fetch();
4.5.3.7.3. GROUP BY ROLLUP
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. ROLLUP
is one way to do this.
SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY ROLLUP (AUTHOR_ID, LANGUAGE_ID)
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()) .from(BOOK) .groupBy(rollup(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID)) .fetch();
The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:
SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID, LANGUAGE_ID UNION ALL SELECT AUTHOR_ID, NULL, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID UNION ALL SELECT NULL, NULL, COUNT(*) FROM BOOK GROUP BY ()
The ROLLUP
function is just syntax sugar for a more complex GROUPING SETS specification. In general:
-- This ROLLUP (A, B, C) -- Is just short for this GROUPING SETS ((A, B, C), (A, B), (A), ())
Dialect support
This example using jOOQ:
select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(rollup(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, MARIADB, MYSQL SELECT BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count(*) FROM BOOK GROUP BY BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID WITH ROLLUP -- AURORA_POSTGRES, DB2, DUCKDB, HANA, MEMSQL, ORACLE, POSTGRES, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TERADATA, -- TRINO, VERTICA SELECT BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count(*) FROM BOOK GROUP BY ROLLUP (BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID) -- ACCESS, ASE, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, REDSHIFT, SQLITE, YUGABYTEDB /* UNSUPPORTED */
4.5.3.7.4. GROUP BY CUBE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. CUBE
is one way to do this.
SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY CUBE (AUTHOR_ID, LANGUAGE_ID)
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()) .from(BOOK) .groupBy(cube(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID)) .fetch();
The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:
SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID, LANGUAGE_ID UNION ALL SELECT AUTHOR_ID, NULL, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID SELECT NULL, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY LANGUAGE_ID UNION ALL SELECT NULL, NULL, COUNT(*) FROM BOOK GROUP BY ()
The CUBE
function is just syntax sugar for a more complex GROUPING SETS specification. In general:
-- This CUBE (A, B, C) -- Is just short for this GROUPING SETS ((A, B, C), (A, B), (A, C), (B, C), (A), (B), (C), ())
Dialect support
This example using jOOQ:
select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(cube(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, DB2, DUCKDB, HANA, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA SELECT BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count(*) FROM BOOK GROUP BY CUBE (BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID) -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, YUGABYTEDB /* UNSUPPORTED */
4.5.3.7.5. GROUP BY GROUPING SETS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In reports, it may be useful to run multiple aggregations across multiple dimensions of the data in one go. GROUPING SETS
is one way to do this.
SELECT AUTHOR_ID, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY GROUPING SETS ((AUTHOR_ID), (LANGUAGE_ID))
create.select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()) .from(BOOK) .groupBy(groupingSets(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID)) .fetch();
The above is a more concise (and possibly more performant) form of writing the following UNION ALL query:
SELECT AUTHOR_ID, NULL AS LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID UNION ALL SELECT NULL, LANGUAGE_ID, COUNT(*) FROM BOOK GROUP BY LANGUAGE_ID
Note that the most common GROUPING SETS
specifications have a dedicated, special syntax:
Dialect support
This example using jOOQ:
select(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count()).from(BOOK).groupBy(groupingSets(BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, DB2, DUCKDB, HANA, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA SELECT BOOK.AUTHOR_ID, BOOK.LANGUAGE_ID, count(*) FROM BOOK GROUP BY GROUPING SETS ( (BOOK.AUTHOR_ID), (BOOK.LANGUAGE_ID) ) -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, YUGABYTEDB /* UNSUPPORTED */
4.5.3.7.6. GROUP BY empty grouping set
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A special kind of GROUPING SET is the empty grouping set, which can be achieved in standard SQL and many SQL dialects using GROUP BY ()
. It is implicit, whenever an aggregate function is present in a query, but not an explicit GROUP BY clause.
SELECT COUNT(*) FROM BOOK GROUP BY ()
create.selectCount() .from(BOOK) .groupBy() .fetch();
Dialect support
This example using jOOQ:
selectCount().from(BOOK).groupBy()
Translates to the following dialect specific expressions:
-- ACCESS SELECT count(*) FROM BOOK, (select count(*) dual from MSysResources) as empty_grouping_dummy_table GROUP BY empty_grouping_dummy_table.dual -- ASE, BIGQUERY, SQLDATAWAREHOUSE SELECT count(*) FROM BOOK, (select 1 as dual) as empty_grouping_dummy_table GROUP BY empty_grouping_dummy_table.dual -- AURORA_MYSQL, MEMSQL SELECT count(*) FROM BOOK GROUP BY (SELECT 1 FROM DUAL) -- AURORA_POSTGRES, DB2, DUCKDB, EXASOL, H2, ORACLE, POSTGRES, SQLSERVER, SYBASE, TERADATA, TRINO SELECT count(*) FROM BOOK GROUP BY () -- COCKROACHDB, MARIADB, MYSQL, REDSHIFT, SQLITE, VERTICA, YUGABYTEDB SELECT count(*) FROM BOOK GROUP BY (SELECT 1) -- DERBY, HSQLDB SELECT count(*) FROM BOOK GROUP BY 0 -- FIREBIRD SELECT count(*) FROM BOOK GROUP BY (SELECT 1 FROM RDB$DATABASE) -- HANA, SNOWFLAKE SELECT count(*) FROM BOOK GROUP BY GROUPING SETS (()) -- INFORMIX SELECT count(*) FROM BOOK, (select 1 as dual from systables where tabid = 1) as empty_grouping_dummy_table GROUP BY empty_grouping_dummy_table.dual
4.5.3.8. HAVING clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The HAVING clause is commonly used to further restrict data resulting from a previously issued GROUP BY clause. An example, selecting only those authors that have written at least two books:
SELECT AUTHOR_ID, COUNT(*) FROM BOOK GROUP BY AUTHOR_ID HAVING COUNT(*) >= 2
create.select(BOOK.AUTHOR_ID, count()) .from(BOOK) .groupBy(AUTHOR_ID) .having(count().ge(2)) .fetch();
According to the SQL standard, you may omit the GROUP BY clause and still issue a HAVING clause. This will implicitly GROUP BY (). jOOQ also supports this syntax. The following example selects one record, only if there are at least 4 books in the books table:
SELECT COUNT(*) FROM BOOK HAVING COUNT(*) >= 4
create.select(count(*)) .from(BOOK) .having(count().ge(4)) .fetch();
4.5.3.9. WINDOW clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL:2003 standard supports a WINDOW
clause that allows for specifying WINDOW
frames for reuse in SELECT clauses and ORDER BY clauses.
SELECT LAG(first_name, 1) OVER w "prev", first_name, LEAD(first_name, 1) OVER w "next" FROM author WINDOW w AS (ORDER first_name) ORDER BY first_name DESC
WindowDefinition w = name("w").as( orderBy(PEOPLE.FIRST_NAME)); create.select( lag(AUTHOR.FIRST_NAME, 1).over(w).as("prev"), AUTHOR.FIRST_NAME, lead(AUTHOR.FIRST_NAME, 1).over(w).as("next")) .from(AUTHOR) .window(w) .orderBy(AUTHOR.FIRST_NAME.desc()) .fetch();
Note that in order to create such a window definition, we need to first create a name reference using DSL.name().
Even if only PostgreSQL and Sybase SQL Anywhere natively support this great feature, jOOQ can emulate it by expanding any org.jooq.WindowDefinition
and org.jooq.WindowSpecification
types that you pass to the window()
method - if the database supports window functions at all.
Some more information about window functions and the WINDOW
clause can be found on our blog: https://blog.jooq.org/probably-the-coolest-sql-feature-window-functions/
4.5.3.10. QUALIFY clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A select few dialects support a very useful QUALIFY
clause, which can be used to filter using window functions without having to nest the window function calculation in a derived table.
For example, if you do not have access to the WITH TIES clause, you could easily emulate it like this. The following query finds the top 5 author WITH TIES, counting their books:
SELECT AUTHOR_ID, count(*) FROM BOOK GROUP BY AUTHOR_ID QUALIFY rank() OVER (ORDER BY count(*) DESC) <= 5 ORDER BY count(*) DESC
create.select(BOOK.AUTHOR_ID, count()) .from(BOOK) .groupBy(BOOK.AUTHOR_ID) .qualify(rank().over(orderBy(count().desc())).le(5)) .orderBy(count().desc()) .fetch();
If your dialect does not support QUALIFY
natively, then jOOQ can apply a transformation from QUALIFY to derived tables.
4.5.3.11. ORDER BY clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Databases are allowed to return data in any arbitrary order, unless you explicitly declare that order in the ORDER BY clause. In jOOQ, this is straight-forward:
SELECT AUTHOR_ID, TITLE FROM BOOK ORDER BY AUTHOR_ID ASC, TITLE DESC
create.select(BOOK.AUTHOR_ID, BOOK.TITLE) .from(BOOK) .orderBy(BOOK.AUTHOR_ID.asc(), BOOK.TITLE.desc()) .fetch();
Any jOOQ column expression (or field) can be transformed into an org.jooq.SortField
by calling the asc() and desc() methods.
Ordering by field index
The SQL standard allows for specifying integer literals (literals, not bind values!) to reference column indexes from the projection (SELECT clause). This may be useful if you do not want to repeat a lengthy expression, by which you want to order - although most databases also allow for referencing aliased column references in the ORDER BY clause. An example of this is given here:
SELECT AUTHOR_ID, TITLE FROM BOOK ORDER BY 1 ASC, 2 DESC
create.select(BOOK.AUTHOR_ID, BOOK.TITLE) .from(BOOK) .orderBy(one().asc(), inline(2).desc()) .fetch();
Note, how one()
is used as a convenience short-cut for inline(1)
Ordering and NULLS
A few databases support the SQL standard "null ordering" clause in sort specification lists, to define whether NULL
values should come first or last in an ordered result.
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME FROM AUTHOR ORDER BY LAST_NAME ASC, FIRST_NAME ASC NULLS LAST
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(AUTHOR) .orderBy(AUTHOR.LAST_NAME.asc(), AUTHOR.FIRST_NAME.asc().nullsLast()) .fetch();
If your database doesn't support this syntax, jOOQ emulates it using a CASE expression as follows
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME FROM AUTHOR ORDER BY LAST_NAME ASC, CASE WHEN FIRST_NAME IS NULL THEN 1 ELSE 0 END ASC, FIRST_NAME ASC
Ordering using CASE expressions
Using CASE expressions in SQL ORDER BY clauses is a common pattern, if you want to introduce some sort indirection / sort mapping into your queries. As with SQL, you can add any type of column expression into your ORDER BY clause. For instance, if you have two favourite books that you always want to appear on top, you could write:
SELECT * FROM BOOK ORDER BY CASE TITLE WHEN '1984' THEN 0 WHEN 'Animal Farm' THEN 1 ELSE 2 END ASC
create.select() .from(BOOK) .orderBy(case_(BOOK.TITLE) .when("1984", 0) .when("Animal Farm", 1) .else_(2).asc()) .fetch();
But writing these things can become quite verbose. jOOQ supports a convenient syntax for specifying sort mappings. The same query can be written in jOOQ as such:
create.select() .from(BOOK) .orderBy(BOOK.TITLE.sortAsc("1984", "Animal Farm")) .fetch();
More complex sort indirections can be provided using a Map:
create.select() .from(BOOK) .orderBy(BOOK.TITLE.sort(new HashMap<String, Integer>() {{ put("1984", 1); put("Animal Farm", 13); put("The jOOQ book", 10); }})) .fetch();
Of course, you can combine this feature with the previously discussed NULLS FIRST / NULLS LAST feature. So, if in fact these two books are the ones you like least, you can put all NULLS FIRST (all the other books):
create.select() .from(BOOK) .orderBy(BOOK.TITLE.sortAsc("1984", "Animal Farm").nullsFirst()) .fetch();
jOOQ's understanding of SELECT .. ORDER BY
The SQL standard defines that a "query expression" can be ordered, and that query expressions can contain UNION, INTERSECT and EXCEPT clauses, whose subqueries cannot be ordered. While this is defined as such in the SQL standard, many databases allowing for the LIMIT clause in one way or another, do not adhere to this part of the SQL standard. Hence, jOOQ allows for ordering all SELECT statements, regardless whether they are constructed as a part of a UNION or not. Corner-cases are handled internally by jOOQ, by introducing synthetic subselects to adhere to the correct syntax, where this is needed.
Oracle's ORDER SIBLINGS BY clause
jOOQ also supports Oracle's SIBLINGS keyword to be used with ORDER BY clauses for hierarchical queries using CONNECT BY
4.5.3.12. LIMIT .. OFFSET clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
While being extremely useful for every application that does pagination, or just to limit result sets to reasonable sizes, this clause has not been standardised up until SQL:2008. Hence, there exist a variety of possible implementations in various SQL dialects, concerning this limit clause. jOOQ chose to implement the LIMIT .. OFFSET clause as understood and supported by MySQL, H2, HSQLDB, Postgres, and SQLite. Here is an example of how to apply limits with jOOQ:
create.select().from(BOOK).orderBy(BOOK.ID).limit(1).offset(2).fetch();
This will limit the result to 1 books skipping the first 2 books (offset 2). limit() is supported in all dialects, offset() in all but Sybase ASE, which has no reasonable means to emulate it. This is how jOOQ trivially emulates the above query in various SQL dialects with native OFFSET
pagination support:
-- MySQL, H2, HSQLDB, and SQLite SELECT * FROM BOOK ORDER BY ID LIMIT 1 OFFSET 2 -- Derby, SQL Server 2012, Oracle 12c, PostgreSQL, the SQL:2008 standard SELECT * FROM BOOK ORDER BY ID OFFSET 2 ROWS FETCH NEXT 1 ROWS ONLY -- Informix has SKIP .. FIRST support SELECT SKIP 2 FIRST 1 * FROM BOOK ORDER BY ID -- Ingres (almost the SQL:2008 standard) SELECT * FROM BOOK ORDER BY ID OFFSET 2 FETCH FIRST 1 ROWS ONLY -- Firebird SELECT * FROM BOOK ORDER BY ID ROWS 2 TO 3 -- Sybase SQL Anywhere SELECT TOP 1 START AT 3 * FROM BOOK ORDER BY ID -- DB2 (almost the SQL:2008 standard, without OFFSET) SELECT * FROM BOOK ORDER BY ID FETCH FIRST 1 ROWS ONLY -- Sybase ASE, SQL Server 2008 (without OFFSET) SELECT TOP 1 * FROM BOOK ORDER BY ID
Things get a little more tricky in those databases that have no native idiom for OFFSET
pagination (actual queries may vary):
-- DB2 (with OFFSET), SQL Server 2008 (with OFFSET) SELECT * FROM ( SELECT BOOK.*, ROW_NUMBER() OVER (ORDER BY ID ASC) AS RN FROM BOOK ) AS X WHERE RN > 2 AND RN <= 3 -- DB2 (with OFFSET), SQL Server 2008 (with OFFSET) SELECT * FROM ( SELECT DISTINCT BOOK.ID, BOOK.TITLE, DENSE_RANK() OVER (ORDER BY ID ASC, TITLE ASC) AS RN FROM BOOK ) AS X WHERE RN > 2 AND RN <= 3 -- Oracle 11g and less SELECT * FROM ( SELECT b.*, ROWNUM RN FROM ( SELECT * FROM BOOK ORDER BY ID ASC ) b WHERE ROWNUM <= 3 ) WHERE RN > 2
As you can see, jOOQ will take care of the incredibly painful ROW_NUMBER() OVER() (or ROWNUM for Oracle) filtering in subselects for you, you'll just have to write limit(1).offset(2) in any dialect.
SQL Server's ORDER BY, TOP and subqueries
As can be seen in the above example, writing correct SQL can be quite tricky, depending on the SQL dialect. For instance, with SQL Server, you cannot have an ORDER BY clause in a subquery, unless you also have a TOP clause. This is illustrated by the fact that jOOQ renders a TOP 100 PERCENT clause for you. The same applies to the fact that ROW_NUMBER() OVER() needs an ORDER BY windowing clause, even if you don't provide one to the jOOQ query. By default, jOOQ adds ordering by the first column of your projection.
Keyset pagination
Note, the LIMIT
clause can also be used with the SEEK clause for keyset pagination.
4.5.3.13. WITH TIES clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
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.
4.5.3.14. SEEK clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
One of the previous chapters talked about OFFSET pagination using LIMIT .. OFFSET
, or OFFSET .. FETCH
or some other vendor-specific variant of the same. This can lead to significant performance issues when reaching a high page number, as all unneeded records need to be skipped by the database.
A much faster and more stable way to perform pagination is the so-called keyset pagination method also called seek method. jOOQ supports a synthetic seek()
clause, that can be used to perform keyset pagination (learn about other synthetic sql syntaxes). Imagine we have these data:
| ID | VALUE | PAGE_BOUNDARY | |------|-------|---------------| | ... | ... | ... | | 474 | 2 | 0 | | 533 | 2 | 1 | <-- Before page 6 | 640 | 2 | 0 | | 776 | 2 | 0 | | 815 | 2 | 0 | | 947 | 2 | 0 | | 37 | 3 | 1 | <-- Last on page 6 | 287 | 3 | 0 | | 450 | 3 | 0 | | ... | ... | ... |
Now, if we want to display page 6 to the user, instead of going to page 6 by using a record OFFSET
, we could just fetch the record strictly after the last record on page 5, which yields the values (533, 2)
. This is how you would do it with SQL or with jOOQ:
SELECT id, value FROM t WHERE (value, id) > (2, 533) ORDER BY value, id LIMIT 5
DSL.using(configuration) .select(T.ID, T.VALUE) .from(T) .orderBy(T.VALUE, T.ID) .seek(lastValue, lastId) // from last page: value = 2, id = 533 .limit(5) .fetch();
As you can see, the jOOQ SEEK
clause is a synthetic clause that does not really exist in SQL. However, the jOOQ syntax is far more intuitive for a variety of reasons:
- It replaces
OFFSET
where you would expect - It doesn't force you to mix regular predicates with "seek" predicates
- It is typesafe
- It emulates row value expression predicates for you, in those databases that do not support them
This query now yields:
| ID | VALUE | |-----|-------| | 640 | 2 | | 776 | 2 | | 815 | 2 | | 947 | 2 | | 37 | 3 |
Note that you cannot combine the SEEK
clause with the OFFSET
clause.
More information about this great feature can be found in the jOOQ blog:
- https://blog.jooq.org/faster-sql-paging-with-jooq-using-the-seek-method/
- https://blog.jooq.org/faster-sql-pagination-with-keysets-continued/
Further information about offset pagination vs. keyset pagination performance can be found on our partner page:
4.5.3.15. FOR clause
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
While both XML and JSON usage in SQL has been standardised in more recent versions of the SQL standard, SQL Server has always had some very convenient utilities at the end of a SELECT statement, which allow for converting SQL tables into the most common XML or JSON representations.
Starting with jOOQ 3.14, these syntaxes are supported in jOOQ as well, and if possible, emulated in other dialects which have native XML or JSON support.
FOR XML
Consider the following query
SELECT id, title FROM book ORDER BY id FOR XML PATH ('book'), ROOT ('books')
create.select(BOOK.ID, BOOK.TITLE) .from(BOOK) .orderBy(BOOK.ID) .forXML().path("book").root("books") .fetch();
This query produces a document like this:
<books> <book><id>1</id><title>1984</title></book> <book><id>2</id><title>Animal Farm</title></book> <book><id>3</id><title>O Alquimista</title></book> <book><id>4</id><title>Brida</title></book> </books>
FOR JSON
JSON is just XML with less syntax and less features. So the FOR JSON
syntax in SQL Server is almost the same as the above FOR XML
syntax:
SELECT id, title FROM book ORDER BY id FOR JSON PATH
create.select(BOOK.ID, BOOK.TITLE) .from(BOOK) .orderBy(BOOK.ID) .forJSON().path() .fetch();
This query produces a document like this:
[ {"id": 1, "title": "1984"}, {"id": 2, "title": "Animal Farm"}, {"id": 3, "title": "O Alquimista"}, {"id": 4, "title": "Brida"} ]
4.5.3.16. FOR UPDATE clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For inter-process synchronisation and other reasons, you may choose to use the SELECT .. FOR UPDATE clause to indicate to the database, that a set of cells or records should be locked by a given transaction for subsequent updates. With jOOQ, this can be achieved as such:
SELECT * FROM BOOK WHERE ID = 3 FOR UPDATE
create.select() .from(BOOK) .where(BOOK.ID.eq(3)) .forUpdate() .fetch();
The above example will produce a record-lock, locking the whole record for updates. Some databases also support cell-locks using FOR UPDATE OF ..
SELECT * FROM BOOK WHERE ID = 3 FOR UPDATE OF TITLE
create.select() .from(BOOK) .where(BOOK.ID.eq(3)) .forUpdate().of(BOOK.TITLE) .fetch();
Oracle goes a bit further and also allows to specify the actual locking behaviour. It features these additional clauses, which are all supported by jOOQ:
-
FOR UPDATE NOWAIT
: This is the default behaviour. If the lock cannot be acquired, the query fails immediately -
FOR UPDATE WAIT n
: Try to wait for [n] seconds for the lock acquisition. The query will fail only afterwards -
FOR UPDATE SKIP LOCKED
: This peculiar syntax will skip all locked records. This is particularly useful when implementing queue tables with multiple consumers
With jOOQ, you can use those Oracle extensions as such:
create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().nowait().fetch(); create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().wait(5).fetch(); create.select().from(BOOK).where(BOOK.ID.eq(3)).forUpdate().skipLocked().fetch();
FOR UPDATE in 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 SQL Server database, that do not allow for any FOR UPDATE
clause in a regular SQL SELECT
statement. jOOQ emulates the FOR UPDATE
behaviour, by locking record by record with JDBC. JDBC allows for specifying the flags TYPE_SCROLL_SENSITIVE
, CONCUR_UPDATABLE
for any statement, and then using ResultSet.updateXXX() methods to produce a cell-lock / row-lock. Here's a simplified example in JDBC:
try ( PreparedStatement stmt = connection.prepareStatement( "SELECT * FROM author WHERE id IN (3, 4, 5)", ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_UPDATABLE); ResultSet rs = stmt.executeQuery() ) { while (rs.next()) { // UPDATE the primary key for row-locks, or any other columns for cell-locks rs.updateObject(1, rs.getObject(1)); rs.updateRow(); // Do more stuff with this record } }
The main drawback of this approach is the fact that the database has to maintain a scrollable cursor, whose records are locked one by one. This can cause a major risk of deadlocks or race conditions if the JDBC driver can recover from the unsuccessful locking, if two Java threads execute the following statements:
-- thread 1 SELECT * FROM author ORDER BY id ASC; -- thread 2 SELECT * FROM author ORDER BY id DESC;
So use this technique with care, possibly only ever locking single rows!
Pessimistic (shared) locking with the FOR SHARE
clause
Some databases (MySQL, Postgres) also allow to issue a non-exclusive lock explicitly using a FOR SHARE
clause. This is also supported by jOOQ
Optimistic locking in jOOQ
Note, that jOOQ also supports optimistic locking, if you're doing simple CRUD. This is documented in the section's manual about optimistic locking.
4.5.3.17. Set operations
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
SQL allows to perform set operations as understood in standard set theory on result sets. These operations include unions, intersections, subtractions. For two subselects to be combinable by such a set operator, each subselect must return a table expression of the same degree and type.
All of these set operations come with 2 flavours:
-
DISTINCT
(the default): Removing duplicates after applying the set operation -
ALL
: Retaining duplicates after applying the set operation
4.5.3.17.1. Type safety
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Two subselects of degree less than 22 that are combined by a set operator are required to be of the same degree and, in most databases, also of the same type. jOOQ 3.0's introduction of Typesafe Record[N] types helps compile-checking these constraints:
// Some sample SELECT statements Select<Record2<Integer, String>> s1 = select(BOOK.ID, BOOK.TITLE).from(BOOK); Select<Record1<Integer>> s2 = selectOne(); Select<Record2<Integer, Integer>> s3 = select(one(), zero()); Select<Record2<Integer, String>> s4 = select(one(), inline("abc")); // Let's try to combine them: s1.union(s2); // Doesn't compile because of a degree mismatch. Expected: Record2<...>, got: Record1<...> s1.union(s3); // Doesn't compile because of a type mismatch. Expected: <Integer, String>, got: <Integer, Integer> s1.union(s4); // OK. The two Record[N] types match
4.5.3.17.2. Projection rowtype
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Much like most dialects use only the first set operation subquery's column names and types for the resulting row type, so does jOOQ.This is particularly interesting when applying converters, including ad-hoc converters or converters attached to generated code.
Since jOOQ does not know which row is produced by which union subquery, it cannot disambiguate these rows in case the projection row type isn't exactly identical. As such, the ad-hoc converter in the following example is ignored:
Result<Record1<Integer>> result = create.select(BOOK.ID) .from(BOOK) .union( // This has no effect select(AUTHOR.ID.convertFrom(i -> -i)) .from(AUTHOR)) .fetch();
While this can lead to subtle bugs, it makes perfect sense, knowing that a Converter
is always applied at the client side of the execution.
4.5.3.17.3. Differences to standard SQL
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
As previously mentioned in the manual's section about the ORDER BY clause, jOOQ has slightly changed the semantics of these set operators. While in SQL, a set operation subselect may not immediately contain any ORDER BY clause or LIMIT clause (unless you wrap the subselect into a derived table), jOOQ allows you to do so. In order to select both the youngest and the oldest author from the database, you can issue the following statement with jOOQ (rendered to the MySQL dialect):
(SELECT * FROM AUTHOR ORDER BY DATE_OF_BIRTH ASC LIMIT 1) UNION (SELECT * FROM AUTHOR ORDER BY DATE_OF_BIRTH DESC LIMIT 1) ORDER BY 1
create.selectFrom(AUTHOR) .orderBy(AUTHOR.DATE_OF_BIRTH.asc()).limit(1) .union( selectFrom(AUTHOR) .orderBy(AUTHOR.DATE_OF_BIRTH.desc()).limit(1)) .orderBy(1) .fetch();
In case your database doesn't support ordered UNION
subselects, the subselects are nested in derived tables.
SELECT * FROM ( SELECT * FROM AUTHOR ORDER BY DATE_OF_BIRTH ASC LIMIT 1 ) UNION SELECT * FROM ( SELECT * FROM AUTHOR ORDER BY DATE_OF_BIRTH DESC LIMIT 1 ) ORDER BY 1
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).orderBy(BOOK.ID).limit(1).union(select(AUTHOR.ID).from(AUTHOR).orderBy(AUTHOR.ID).limit(1)).orderBy(1)
Translates to the following dialect specific expressions:
-- ACCESS, ASE, SQLDATAWAREHOUSE, SYBASE ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ) UNION ( SELECT TOP 1 AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID ) ORDER BY 1 -- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, HANA, HSQLDB, MYSQL, REDSHIFT, SNOWFLAKE, VERTICA, -- YUGABYTEDB ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID LIMIT 1 ) UNION ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID LIMIT 1 ) ORDER BY 1 -- BIGQUERY ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID LIMIT 1 ) UNION DISTINCT ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID LIMIT 1 ) ORDER BY 1 -- DB2 ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) UNION ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID FETCH NEXT 1 ROWS ONLY ) ORDER BY 1 -- DERBY, H2, MARIADB, ORACLE, POSTGRES, TRINO ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID FETCH NEXT 1 ROWS ONLY ) UNION ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID FETCH NEXT 1 ROWS ONLY ) ORDER BY 1 -- FIREBIRD SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID FETCH NEXT 1 ROWS ONLY UNION SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID FETCH NEXT 1 ROWS ONLY ORDER BY 1 -- INFORMIX ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) UNION ( SELECT * FROM ( SELECT FIRST 1 AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID ) x ) ORDER BY 1 -- MEMSQL SELECT t.* FROM ( ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID LIMIT 1 ) UNION ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID LIMIT 1 ) ) t ORDER BY 1 -- SQLITE SELECT * FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID LIMIT 1 ) x UNION SELECT * FROM ( SELECT AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID LIMIT 1 ) x ORDER BY 1 -- SQLSERVER ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY ) UNION ( SELECT TOP 1 AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID ) ORDER BY 1 -- TERADATA ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ) UNION ( SELECT * FROM ( SELECT TOP 1 AUTHOR.ID FROM AUTHOR ORDER BY AUTHOR.ID ) x ) ORDER BY 1
4.5.3.17.4. UNION
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A UNION
operation combines two subquery results of compatible row type into a single result. While UNION
removes all duplicate records resulting from this combination, UNION ALL
leaves subselect results as they are. Typically, you should prefer UNION ALL
over UNION
, if you don't really need to remove duplicates, see also this section of the manual. The following example shows how to use such a UNION
operation in jOOQ.
SELECT * FROM BOOK WHERE ID = 3 UNION ALL SELECT * FROM BOOK WHERE ID = 5
create.selectFrom(BOOK).where(BOOK.ID.eq(3)) .unionAll( create.selectFrom(BOOK).where(BOOK.ID.eq(5))) .fetch();
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).union(select(AUTHOR.ID).from(AUTHOR)).orderBy(BOOK.ID)
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, -- MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, -- YUGABYTEDB SELECT BOOK.ID FROM BOOK UNION SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- BIGQUERY SELECT BOOK.ID FROM BOOK UNION DISTINCT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- FIREBIRD SELECT BOOK.ID FROM BOOK UNION SELECT AUTHOR.ID FROM AUTHOR ORDER BY 1 -- MEMSQL SELECT t.* FROM ( SELECT BOOK.ID FROM BOOK UNION SELECT AUTHOR.ID FROM AUTHOR ) t ORDER BY ID
4.5.3.17.5. INTERSECT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
INTERSECT
is the operation that produces only those values that are returned by both subselects. By default, this removes duplicate rows. Use INTERSECT ALL
in order to retain them, and require duplicates to appear in both subqueries.
SELECT ID FROM BOOK INTERSECT ALL SELECT ID FROM AUTHOR
create.select(BOOK.ID).from(BOOK) .intersectAll( create.select(AUTHOR.ID).from(AUTHOR)) .fetch();
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).intersect(select(AUTHOR.ID).from(AUTHOR)).orderBy(BOOK.ID)
Translates to the following dialect specific expressions:
-- ASE, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, -- SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB SELECT BOOK.ID FROM BOOK INTERSECT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- BIGQUERY SELECT BOOK.ID FROM BOOK INTERSECT DISTINCT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- MEMSQL SELECT t.* FROM ( SELECT BOOK.ID FROM BOOK INTERSECT SELECT AUTHOR.ID FROM AUTHOR ) t ORDER BY ID -- ACCESS, AURORA_MYSQL, DUCKDB, FIREBIRD, REDSHIFT /* UNSUPPORTED */
4.5.3.17.6. EXCEPT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
EXCEPT
(or MINUS
in Oracle) is the operation that returns only those values that are returned exclusively in the first subselect. By default, this removes duplicate rows. Use EXCEPT ALL
in order to retain them, and require duplicates to appear in both subqueries.
SELECT ID FROM BOOK EXCEPT ALL SELECT ID FROM AUTHOR
create.select(BOOK.ID).from(BOOK) .exceptAll( create.select(AUTHOR.ID).from(AUTHOR)) .fetch();
Dialect support
This example using jOOQ:
select(BOOK.ID).from(BOOK).except(select(AUTHOR.ID).from(AUTHOR)).orderBy(BOOK.ID)
Translates to the following dialect specific expressions:
-- ASE, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, POSTGRES, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB SELECT BOOK.ID FROM BOOK EXCEPT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- BIGQUERY SELECT BOOK.ID FROM BOOK EXCEPT DISTINCT SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- MEMSQL SELECT t.* FROM ( SELECT BOOK.ID FROM BOOK EXCEPT SELECT AUTHOR.ID FROM AUTHOR ) t ORDER BY ID -- ORACLE SELECT BOOK.ID FROM BOOK MINUS SELECT AUTHOR.ID FROM AUTHOR ORDER BY ID -- ACCESS, AURORA_MYSQL, DUCKDB, FIREBIRD, REDSHIFT /* UNSUPPORTED */
4.5.3.18. Lexical and logical SELECT clause order
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
SQL has a lexical and a logical order of SELECT
clauses. The lexical order of SELECT
clauses is inspired by the English language. As SQL statements are commands for the database, it is natural to express a statement in an imperative tense, such as "SELECT this and that!".
Logical SELECT clause order
The logical order of SELECT
clauses, however, does not correspond to the syntax. In fact, the logical order is this:
- The FROM clause: First, all data sources are defined and joined
- The WHERE clause: Then, data is filtered as early as possible
- The CONNECT BY clause: Then, data is traversed iteratively or recursively, to produce new tuples
- The GROUP BY clause: Then, data is reduced to groups, possibly producing new tuples if grouping functions like ROLLUP(), CUBE(), GROUPING SETS() are used
- The HAVING clause: Then, data is filtered again
-
The SELECT clause: Only now, the projection is evaluated. In case of a
SELECT DISTINCT
statement, data is further reduced to remove duplicates -
UNION, INTERSECT and EXCEPT clauses: Optionally, the above is repeated for several
UNION
-connected subqueries. Unless this is aUNION ALL
clause, data is further reduced to remove duplicates - The ORDER BY clause: Now, all remaining tuples are ordered
- The LIMIT clause: Then, a paginating view is created for the ordered tuples
- The FOR clause: Transformation to XML or JSON
- The FOR UPDATE clause: Finally, pessimistic locking is applied
The SQL Server documentation also explains this, with slightly different clauses:
-
FROM
-
ON
-
JOIN
-
WHERE
-
GROUP BY
-
WITH CUBE
orWITH ROLLUP
-
HAVING
-
SELECT
-
DISTINCT
-
ORDER BY
-
TOP
As can be seen, databases have to logically reorder a SQL statement in order to determine the best execution plan.
Alternative syntaxes: LINQ, SLICK
Some "higher-level" abstractions, such as C#'s LINQ or Scala's SLICK try to inverse the lexical order of SELECT
clauses to what appears to be closer to the logical order. The obvious advantage of moving the SELECT
clause to the end is the fact that the projection type, which is the record type returned by the SELECT
statement can be re-used more easily in the target environment of the internal domain specific language.
A LINQ example:
// LINQ-to-SQL looks somewhat similar to SQL // AS clause // FROM clause From p In db.Products // WHERE clause Where p.UnitsInStock <= p.ReorderLevel AndAlso Not p.Discontinued // SELECT clause Select p
A SLICK example:
// "for" is the "entry-point" to the DSL val q = for { // FROM clause WHERE clause c <- Coffees if c.supID === 101 // SELECT clause and projection to a tuple } yield (c.name, c.price)
While this looks like a good idea at first, it only complicates translation to more advanced SQL statements while impairing readability for those users that are used to writing SQL. jOOQ is designed to look just like SQL. This is specifically true for SLICK, which not only changed the SELECT
clause order, but also heavily "integrated" SQL clauses with the Scala language.
For these reasons, the jOOQ DSL API is modelled in SQL's lexical order.
4.5.4. The INSERT statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The INSERT
statement is used to insert new records into a database table. The following sections describe the various operation modes of the jOOQ INSERT
statement.
4.5.4.1. INSERT .. VALUES
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
INSERT .. VALUES with a single row
Records can either be supplied using a VALUES()
constructor, or a SELECT
statement. jOOQ supports both types of INSERT
statements. An example of an INSERT
statement using a VALUES()
constructor is given here:
INSERT INTO AUTHOR (ID, FIRST_NAME, LAST_NAME) VALUES (100, 'Hermann', 'Hesse');
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .values(100, "Hermann", "Hesse") .execute();
Note that for explicit degrees up to 22, the VALUES()
constructor provides additional typesafety. The following example illustrates this:
InsertValuesStep3<AuthorRecord, Integer, String, String> step = create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME); step.values("A", "B", "C"); // ^^^ Doesn't compile, the expected type is Integer
INSERT .. VALUES with multiple rows
The SQL standard specifies that multiple rows can be supplied to the VALUES() constructor in an INSERT statement. Here's an example of a multi-record INSERT
INSERT INTO AUTHOR (ID, FIRST_NAME, LAST_NAME) VALUES (100, 'Hermann', 'Hesse'), (101, 'Alfred', 'Döblin');
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .values(100, "Hermann", "Hesse") .values(101, "Alfred", "Döblin") .execute()
jOOQ tries to stay close to actual SQL. In detail, however, Java's expressiveness is limited. That's why the values() clause is repeated for every record in multi-record inserts.
Some RDBMS do not support inserting several records in a single statement. In those cases, jOOQ emulates multi-record INSERTs using the following SQL:
INSERT INTO AUTHOR (ID, FIRST_NAME, LAST_NAME) SELECT 100, 'Hermann', 'Hesse' FROM DUAL UNION ALL SELECT 101, 'Alfred', 'Döblin' FROM DUAL;
create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .values(100, "Hermann", "Hesse") .values(101, "Alfred", "Döblin") .execute();
If your inserted rows or records are dynamic, you can use valuesOfRows()
or valuesOfRecords()
instead:
INSERT INTO AUTHOR (ID, FIRST_NAME, LAST_NAME) VALUES (100, 'Hermann', 'Hesse'), (101, 'Alfred', 'Döblin');
List<Record3<Integer, String, String>> records = ... create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .valuesOfRecords(records) .execute();
4.5.4.2. INSERT .. DEFAULT VALUES
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A lesser-known syntactic feature of SQL is the INSERT .. DEFAULT VALUES
statement, where a single record is inserted, containing only DEFAULT
values for every row. It is written as such:
INSERT INTO AUTHOR DEFAULT VALUES;
create.insertInto(AUTHOR) .defaultValues() .execute();
This can make a lot of sense in situations where you want to "reserve" a row in the database for an subsequent UPDATE statement within the same transaction. Or if you just want to send an event containing trigger-generated default values, such as IDs or timestamps.
The DEFAULT VALUES
clause is not supported in all databases, but jOOQ can emulate it using the equivalent statement:
INSERT INTO AUTHOR (ID, FIRST_NAME, LAST_NAME, ...) VALUES ( DEFAULT, DEFAULT, DEFAULT, ...);
create.insertInto( AUTHOR, AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, ...) .values( defaultValue(AUTHOR.ID), defaultValue(AUTHOR.FIRST_NAME), defaultValue(AUTHOR.LAST_NAME), ...) .execute();
The DEFAULT
keyword (or DSL#defaultValue() method) can also be used for individual columns only, although that will have the same effect as leaving the column away entirely.
4.5.4.3. INSERT .. SET
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
MySQL (and some other RDBMS) allow for using a non-SQL-standard, UPDATE-like syntax for INSERT statements. This is also supported in jOOQ (and emulated for all databases), should you prefer that syntax. The above INSERT statement can also be expressed as follows:
create.insertInto(AUTHOR) .set(AUTHOR.ID, 100) .set(AUTHOR.FIRST_NAME, "Hermann") .set(AUTHOR.LAST_NAME, "Hesse") .newRecord() .set(AUTHOR.ID, 101) .set(AUTHOR.FIRST_NAME, "Alfred") .set(AUTHOR.LAST_NAME, "Döblin") .execute();
As you can see, this syntax is a bit more verbose, but also more readable, as every field can be matched with its value. Internally, the two syntaxes are strictly equivalent.
4.5.4.4. INSERT .. SELECT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In some occasions, you may prefer the INSERT SELECT syntax, for instance, when you copy records from one table to another:
create.insertInto(AUTHOR_ARCHIVE) .select(selectFrom(AUTHOR).where(AUTHOR.DECEASED.isTrue())) .execute();
4.5.4.5. INSERT .. ON DUPLICATE KEY UPDATE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ON DUPLICATE KEY UPDATE clause
The MySQL database supports a very convenient way to INSERT or UPDATE a record. This is a non-standard extension to the SQL syntax, which is supported by jOOQ and emulated in other RDBMS, where this is possible (e.g. if they support the SQL standard MERGE statement). Here is an example how to use the ON DUPLICATE KEY UPDATE clause:
// Add a new author called "Koontz" with ID 3. // If that ID is already present, update the author's name create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME) .values(3, "Koontz") .onDuplicateKeyUpdate() .set(AUTHOR.LAST_NAME, "Koontz") .execute();
Dialect support
This example using jOOQ:
insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onDuplicateKeyUpdate().set(AUTHOR.LAST_NAME, "X")
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON DUPLICATE KEY UPDATE AUTHOR.LAST_NAME = 'X' -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, YUGABYTEDB INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON CONFLICT (ID) DO UPDATE SET LAST_NAME = 'X' -- DB2 MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYSIBM.DUAL ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- DERBY MERGE INTO AUTHOR USING SYSIBM.SYSDUMMY1 ON AUTHOR.ID = 3 WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( 3, 'X' ) -- EXASOL MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- FIREBIRD MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM RDB$DATABASE ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- H2 MERGE INTO AUTHOR USING ( SELECT 3 ID, 'X' LAST_NAME ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HANA MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME FROM SYS.DUMMY ) ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HSQLDB MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM (VALUES(1)) AS dual(dual) ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ORACLE MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME ) ) t ON (AUTHOR.ID = t.ID) WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SNOWFLAKE MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SQLITE INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON CONFLICT DO UPDATE SET LAST_NAME = 'X' -- SQLSERVER MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ); -- SYBASE MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYS.DUMMY ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- TERADATA MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM ( SELECT 1 AS "dual" ) AS "dual" ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ACCESS, ASE, BIGQUERY, INFORMIX, REDSHIFT, SQLDATAWAREHOUSE, TRINO, VERTICA /* UNSUPPORTED */
4.5.4.6. INSERT .. ON DUPLICATE KEY IGNORE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The MySQL database also supports an INSERT IGNORE INTO clause. This is supported by jOOQ using the more convenient SQL syntax variant of ON DUPLICATE KEY IGNORE:
// Add a new author called "Koontz" with ID 3. // If that ID is already present, ignore the INSERT statement create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME) .values(3, "Koontz") .onDuplicateKeyIgnore() .execute();
If the underlying database doesn't have any way to "ignore" failing INSERT
statements, (e.g. MySQL via INSERT IGNORE
), jOOQ can emulate the statement using a MERGE statement, or using INSERT .. SELECT WHERE NOT EXISTS.
The MySQL INSERT IGNORE
statement ignores more constraint violations than just duplicate keys, so the emulation isn't exactly equivalent, see #5211
Dialect support
This example using jOOQ:
insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onDuplicateKeyIgnore()
Translates to the following dialect specific expressions:
-- ACCESS INSERT INTO AUTHOR (ID, LAST_NAME) SELECT t.v0, t.v1 FROM ( SELECT 3 v0, 'X' v1 FROM ( SELECT count(*) dual FROM MSysResources ) AS dual WHERE NOT EXISTS ( SELECT 1 one FROM AUTHOR WHERE AUTHOR.ID = 3 ) ) t -- ASE, REDSHIFT, SQLDATAWAREHOUSE, TRINO, VERTICA INSERT INTO AUTHOR (ID, LAST_NAME) SELECT t.v0, t.v1 FROM ( SELECT 3 v0, 'X' v1 WHERE NOT EXISTS ( SELECT 1 one FROM AUTHOR WHERE AUTHOR.ID = 3 ) ) t -- AURORA_MYSQL, MARIADB, MYSQL INSERT IGNORE INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, SQLITE, YUGABYTEDB INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON CONFLICT DO NOTHING -- BIGQUERY INSERT INTO AUTHOR (ID, LAST_NAME) SELECT t.v0, t.v1 FROM ( SELECT 3 v0, 'X' v1 FROM UNNEST([STRUCT(1 AS dual)]) AS dual WHERE NOT EXISTS ( SELECT 1 one FROM AUTHOR WHERE AUTHOR.ID = 3 ) ) t -- DB2 MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYSIBM.DUAL ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- DERBY MERGE INTO AUTHOR USING SYSIBM.SYSDUMMY1 ON AUTHOR.ID = 3 WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( 3, 'X' ) -- EXASOL, MEMSQL INSERT INTO AUTHOR (ID, LAST_NAME) SELECT t.v0, t.v1 FROM ( SELECT 3 v0, 'X' v1 FROM DUAL WHERE NOT EXISTS ( SELECT 1 one FROM AUTHOR WHERE AUTHOR.ID = 3 ) ) t -- FIREBIRD MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM RDB$DATABASE ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- H2 MERGE INTO AUTHOR USING ( SELECT 3 ID, 'X' LAST_NAME ) t ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HANA MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME FROM SYS.DUMMY ) ) t ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HSQLDB MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM (VALUES(1)) AS dual(dual) ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- INFORMIX INSERT INTO AUTHOR (ID, LAST_NAME) SELECT t.v0, t.v1 FROM ( SELECT 3 v0, 'X' v1 FROM ( SELECT 1 AS dual FROM systables WHERE (tabid = 1) ) AS dual WHERE NOT EXISTS ( SELECT 1 one FROM AUTHOR WHERE AUTHOR.ID = 3 ) ) t -- ORACLE MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME ) ) t ON (AUTHOR.ID = t.ID) WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SNOWFLAKE MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SQLSERVER MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ); -- SYBASE MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYS.DUMMY ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- TERADATA MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM ( SELECT 1 AS "dual" ) AS "dual" ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME )
4.5.4.7. INSERT .. ON CONFLICT .. EXCLUDED
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A special use-case for INSERT .. ON CONFLICT is an UPSERT
statement where all (or most of) the values to be updated are the same values that would have been inserted if there wasn't a conflict - with the exception of primary keys. In PostgreSQL, this is done using the EXCLUDED
pseudo table. The keyword should be read as "rows that have been excluded from the INSERT
part of the statement."
// Add a new author called "Koontz" with ID 3. // If that ID is already present, update the author's name create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME) .values(3, "Koontz") .onConflict(AUTHOR.ID) .doUpdate() .set(AUTHOR.LAST_NAME, excluded(AUTHOR.LAST_NAME)) .execute();
Dialect support
This example using jOOQ:
insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onConflict(AUTHOR.ID).doUpdate().set(AUTHOR.LAST_NAME, excluded(AUTHOR.LAST_NAME))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, SQLITE, YUGABYTEDB INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON CONFLICT (ID) DO UPDATE SET LAST_NAME = excluded.LAST_NAME -- DB2 MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYSIBM.DUAL ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- DERBY MERGE INTO AUTHOR USING SYSIBM.SYSDUMMY1 ON AUTHOR.ID = 3 WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( 3, 'X' ) -- EXASOL MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- FIREBIRD MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM RDB$DATABASE ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- H2 MERGE INTO AUTHOR USING ( SELECT 3 ID, 'X' LAST_NAME ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HANA MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME FROM SYS.DUMMY ) ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HSQLDB MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM (VALUES(1)) AS dual(dual) ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ORACLE MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME ) ) t ON (AUTHOR.ID = t.ID) WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SQLSERVER MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ); -- SYBASE MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYS.DUMMY ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- TERADATA MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM ( SELECT 1 AS "dual" ) AS "dual" ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET LAST_NAME = t.LAST_NAME WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, TRINO, -- VERTICA /* UNSUPPORTED */
4.5.4.8. INSERT .. ON CONFLICT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The PostgreSQL database offers an alternative syntax to MySQL's vendor specific INSERT .. ON DUPLICATE KEY syntax, which allows for specifying an explicit (reference by constraint name) or implicit (reference by column list) unique constraint for conflict resolution.
// Add a new author called "Koontz" with ID 3. // If that ID is already present, update the author's name create.insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME) .values(3, "Koontz") .onConflict(AUTHOR.ID) .doUpdate() .set(AUTHOR.LAST_NAME, "Koontz") .execute();
Dialect support
This example using jOOQ:
insertInto(AUTHOR, AUTHOR.ID, AUTHOR.LAST_NAME).values(3, "X").onConflict(AUTHOR.ID).doUpdate().set(AUTHOR.LAST_NAME, "X")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, SQLITE, YUGABYTEDB INSERT INTO AUTHOR (ID, LAST_NAME) VALUES ( 3, 'X' ) ON CONFLICT (ID) DO UPDATE SET LAST_NAME = 'X' -- DB2 MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYSIBM.DUAL ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- DERBY MERGE INTO AUTHOR USING SYSIBM.SYSDUMMY1 ON AUTHOR.ID = 3 WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( 3, 'X' ) -- EXASOL MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- FIREBIRD MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM RDB$DATABASE ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- H2 MERGE INTO AUTHOR USING ( SELECT 3 ID, 'X' LAST_NAME ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HANA MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME FROM SYS.DUMMY ) ) t ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- HSQLDB MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM (VALUES(1)) AS dual(dual) ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ORACLE MERGE INTO AUTHOR USING ( ( SELECT 3 ID, 'X' LAST_NAME ) ) t ON (AUTHOR.ID = t.ID) WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- SQLSERVER MERGE INTO AUTHOR USING ( SELECT 3, 'X' ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ); -- SYBASE MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM SYS.DUMMY ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET AUTHOR.LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- TERADATA MERGE INTO AUTHOR USING ( SELECT 3, 'X' FROM ( SELECT 1 AS "dual" ) AS "dual" ) t (ID, LAST_NAME) ON AUTHOR.ID = t.ID WHEN MATCHED THEN UPDATE SET LAST_NAME = 'X' WHEN NOT MATCHED THEN INSERT (ID, LAST_NAME) VALUES ( t.ID, t.LAST_NAME ) -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, TRINO, -- VERTICA /* UNSUPPORTED */
4.5.4.9. INSERT .. RETURNING
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The Postgres database has native support for an INSERT .. RETURNING clause. This is a very powerful concept that is emulated for all other dialects using JDBC's getGeneratedKeys() method. Take this example:
// Add another author, with a generated ID Record record = create.insertInto(AUTHOR, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .values("Charlotte", "Roche") .returningResult(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 .returningResult(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 returningResult() clause.
Dialect support
This example using jOOQ:
insertInto(AUTHOR, AUTHOR.LAST_NAME).values("Doe").returningResult(AUTHOR.ID)
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, -- SYBASE, TERADATA, TRINO, VERTICA INSERT INTO AUTHOR (LAST_NAME) VALUES ('Doe') -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, FIREBIRD, POSTGRES, SQLITE, YUGABYTEDB INSERT INTO AUTHOR (LAST_NAME) VALUES ('Doe') RETURNING AUTHOR.ID -- DB2, H2 SELECT ID FROM FINAL TABLE ( INSERT INTO AUTHOR (LAST_NAME) VALUES ('Doe') ) AUTHOR -- MARIADB INSERT INTO AUTHOR (LAST_NAME) VALUES ('Doe') RETURNING ID -- SQLDATAWAREHOUSE, SQLSERVER INSERT INTO AUTHOR (LAST_NAME) OUTPUT inserted.ID VALUES ('Doe')
4.5.5. The UPDATE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The UPDATE
statement is used to modify one or several pre-existing records in a database table. UPDATE
statements are only possible on single tables. Support for multi-table updates might be implemented in the future. An example update query is given here:
UPDATE AUTHOR SET FIRST_NAME = 'Hermann', LAST_NAME = 'Hesse' WHERE ID = 3;
create.update(AUTHOR) .set(AUTHOR.FIRST_NAME, "Hermann") .set(AUTHOR.LAST_NAME, "Hesse") .where(AUTHOR.ID.eq(3)) .execute();
The following subsections discuss the various subclauses of the DELETE
statement.
4.5.5.1. UPDATE .. SET
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SET
clause allows for setting new values on updated records in a table.
Dialect support
This example using jOOQ:
update(BOOK).set(BOOK.TITLE, "New Title")
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, -- SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO UPDATE BOOK SET BOOK.TITLE = 'New Title' -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA, YUGABYTEDB UPDATE BOOK SET TITLE = 'New Title' -- BIGQUERY UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE TRUE -- HANA UPDATE BOOK FROM BOOK SET BOOK.TITLE = 'New Title'
4.5.5.2. UPDATE .. SET ROWS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SET
clause allows for setting ROW value expressions on updated records in a table.
UPDATE AUTHOR SET (FIRST_NAME, LAST_NAME) = ('Hermann', 'Hesse') WHERE ID = 3;
create.update(AUTHOR) .set(row(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME), row("Herman", "Hesse")) .where(AUTHOR.ID.eq(3)) .execute();
This can be particularly useful when using correlated subqueries in the SET
clause, in case of which multiple columns can be updated with a single subquery, instead of only 1. See also UPDATE .. FROM for an alternative syntax for this scenario.
UPDATE AUTHOR SET (FIRST_NAME, LAST_NAME) = ( SELECT PERSON.FIRST_NAME, PERSON.LAST_NAME FROM PERSON WHERE PERSON.ID = AUTHOR.ID ) WHERE ID = 3;
create.update(AUTHOR) .set(row(AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME), select(PERSON.FIRST_NAME, PERSON.LAST_NAME) .from(PERSON) .where(PERSON.ID.eq(AUTHOR.ID)) ) .where(AUTHOR.ID.eq(3)) .execute();
The above row value expressions usages are completely typesafe.
Dialect support
This example using jOOQ:
update(BOOK).set(row(BOOK.TITLE, BOOK.LANGUAGE_ID), row("New Title", 1))
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, DERBY, EXASOL, FIREBIRD, INFORMIX, MARIADB, MEMSQL, MYSQL, SQLDATAWAREHOUSE, SQLSERVER, -- SYBASE UPDATE BOOK SET BOOK.TITLE = 'New Title', BOOK.LANGUAGE_ID = 1 -- AURORA_POSTGRES, COCKROACHDB, DB2, H2, HSQLDB, TRINO UPDATE BOOK SET (TITLE, LANGUAGE_ID) = ('New Title', 1) -- BIGQUERY UPDATE BOOK SET BOOK.TITLE = 'New Title', BOOK.LANGUAGE_ID = 1 WHERE TRUE -- DUCKDB, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA UPDATE BOOK SET TITLE = 'New Title', LANGUAGE_ID = 1 -- HANA UPDATE BOOK FROM BOOK SET (TITLE, LANGUAGE_ID) = ('New Title', 1) -- ORACLE UPDATE BOOK SET (TITLE, LANGUAGE_ID) = ( SELECT 'New Title', 1 ) -- POSTGRES, YUGABYTEDB UPDATE BOOK SET (TITLE, LANGUAGE_ID) = ROW ('New Title', 1)
4.5.5.3. UPDATE .. FROM
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some databases, including for example PostgreSQL and SQL Server, support joining additional tables to an UPDATE
statement using a vendor-specific FROM
clause. This is supported as well by jOOQ:
UPDATE BOOK_ARCHIVE SET BOOK_ARCHIVE.TITLE = BOOK.TITLE FROM BOOK WHERE BOOK_ARCHIVE.ID = BOOK.ID
create.update(BOOK_ARCHIVE) .set(BOOK_ARCHIVE.TITLE, BOOK.TITLE) .from(BOOK) .where(BOOK_ARCHIVE.ID.eq(BOOK.ID)) .execute();
In many cases, such a joined update statement can be emulated using a correlated subquery, or using updatable views. For example, most databases allow for using scalar subselects in UPDATE
statements in one way or another. jOOQ models this through a set(Field<T>, Select<? extends Record1<T>>)
method in the UPDATE
DSL API, for convenience (see the section about scalar subqueries for more details):
UPDATE AUTHOR SET FIRST_NAME = ( SELECT FIRST_NAME FROM PERSON WHERE PERSON.ID = AUTHOR.ID ), WHERE ID = 3;
create.update(AUTHOR) .set(AUTHOR.FIRST_NAME, select(PERSON.FIRST_NAME) .from(PERSON) .where(PERSON.ID.eq(AUTHOR.ID)) ) .where(AUTHOR.ID.eq(3)) .execute();
Dialect support
This example using jOOQ:
update(BOOK_TO_BOOK_STORE).set(BOOK_TO_BOOK_STORE.STOCK, 0).from(BOOK).where(BOOK_TO_BOOK_STORE.BOOK_ID.eq(BOOK.ID)).and(BOOK.AUTHOR_ID.eq(1))
Translates to the following dialect specific expressions:
-- ASE, BIGQUERY, ORACLE, SQLSERVER, SYBASE UPDATE BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = 0 FROM BOOK WHERE ( BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID AND BOOK.AUTHOR_ID = 1 ) -- AURORA_POSTGRES, COCKROACHDB, POSTGRES, SNOWFLAKE, SQLITE UPDATE BOOK_TO_BOOK_STORE SET STOCK = 0 FROM BOOK WHERE ( BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID AND BOOK.AUTHOR_ID = 1 ) -- DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB MERGE INTO BOOK_TO_BOOK_STORE USING BOOK ON ( BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID AND BOOK.AUTHOR_ID = 1 ) WHEN MATCHED THEN UPDATE SET BOOK_TO_BOOK_STORE.STOCK = 0 -- HANA UPDATE BOOK_TO_BOOK_STORE FROM BOOK_TO_BOOK_STORE, BOOK SET BOOK_TO_BOOK_STORE.STOCK = 0 WHERE ( BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID AND BOOK.AUTHOR_ID = 1 ) -- TERADATA, VERTICA MERGE INTO BOOK_TO_BOOK_STORE USING BOOK ON ( BOOK_TO_BOOK_STORE.BOOK_ID = BOOK.ID AND BOOK.AUTHOR_ID = 1 ) WHEN MATCHED THEN UPDATE SET STOCK = 0 -- ACCESS, AURORA_MYSQL, DUCKDB, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, TRINO, YUGABYTEDB /* UNSUPPORTED */
4.5.5.4. UPDATE .. WHERE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The WHERE
clause allows for adding a conditional expressions to the UPDATE
statement, which restricts the rows to be updated.
Dialect support
This example using jOOQ:
update(BOOK).set(BOOK.TITLE, "New Title").where(BOOK.ID.eq(1))
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, -- ORACLE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID = 1 -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, TERADATA, VERTICA, YUGABYTEDB UPDATE BOOK SET TITLE = 'New Title' WHERE BOOK.ID = 1 -- HANA UPDATE BOOK FROM BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID = 1
4.5.5.5. UPDATE .. ORDER BY .. LIMIT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ORDER BY
and LIMIT
clauses allow for updating only a subset of the data in a table, based on their ordering. This can be useful to implement queue semantics, e.g. to update only the top row, and possibly return it in one go.
Dialect support
This example using jOOQ:
update(BOOK).set(BOOK.TITLE, "New Title").orderBy(BOOK.ID.asc()).limit(1)
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, DB2, MARIADB, MYSQL, TRINO UPDATE BOOK SET BOOK.TITLE = 'New Title' ORDER BY BOOK.ID ASC LIMIT 1 -- AURORA_POSTGRES, DUCKDB, REDSHIFT, SNOWFLAKE, SQLITE, VERTICA, YUGABYTEDB UPDATE BOOK SET TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) -- BIGQUERY, EXASOL, HSQLDB UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) -- COCKROACHDB UPDATE BOOK SET TITLE = 'New Title' ORDER BY BOOK.ID ASC LIMIT 1 -- DERBY, H2, ORACLE UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC FETCH NEXT 1 ROWS ONLY ) -- FIREBIRD UPDATE BOOK SET BOOK.TITLE = 'New Title' ORDER BY BOOK.ID ASC ROWS 1 -- HANA UPDATE BOOK FROM BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) -- INFORMIX UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT * FROM ( SELECT FIRST 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) x ) -- MEMSQL UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT * FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) t ) -- POSTGRES UPDATE BOOK SET TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC FETCH NEXT 1 ROWS ONLY ) -- SQLDATAWAREHOUSE, SQLSERVER, SYBASE UPDATE BOOK SET BOOK.TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) -- TERADATA UPDATE BOOK SET TITLE = 'New Title' WHERE BOOK.ID IN ( SELECT * FROM ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) x ) -- ACCESS, ASE /* UNSUPPORTED */
4.5.5.6. UPDATE .. RETURNING
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Various dialect support a RETURNING
clause or something similar on their UPDATE
statements, similar as the RETURNING
clause in INSERT statements. This is useful to fetch trigger-generated values in one go. An example is given here:
-- Fetch a trigger-generated value UPDATE BOOK SET TITLE = 'Animal Farm' WHERE ID = 5 RETURNING TITLE
String title = create.update(BOOK) .set(BOOK.TITLE, "Animal Farm") .where(BOOK.ID.eq(5)) .returningResult(BOOK.TITLE) .fetchOne().getValue(BOOK.TITLE);
Dialect support
This example using jOOQ:
update(BOOK).set(BOOK.TITLE, "New Title").returningResult(BOOK.ID)
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, SQLITE, YUGABYTEDB UPDATE BOOK SET TITLE = 'New Title' RETURNING BOOK.ID -- DB2, H2 SELECT ID FROM FINAL TABLE ( UPDATE BOOK SET BOOK.TITLE = 'New Title' ) BOOK -- FIREBIRD UPDATE BOOK SET BOOK.TITLE = 'New Title' RETURNING BOOK.ID -- MARIADB INSERT INTO BOOK ( ID, AUTHOR_ID, TITLE, PUBLISHED_IN, LANGUAGE_ID ) SELECT BOOK.ID, BOOK.AUTHOR_ID, BOOK.TITLE, BOOK.PUBLISHED_IN, BOOK.LANGUAGE_ID FROM BOOK ON DUPLICATE KEY UPDATE BOOK.TITLE = 'New Title' RETURNING ID -- ORACLE DECLARE o0 DBMS_SQL.NUMBER_TABLE; c0 sys_refcursor; BEGIN UPDATE BOOK SET BOOK.TITLE = 'New Title' RETURNING BOOK.ID BULK COLLECT INTO o0; ? := SQL%ROWCOUNT; OPEN c0 FOR SELECT * FROM TABLE(o0); ? := c0; END; -- SQLSERVER UPDATE BOOK SET BOOK.TITLE = 'New Title' OUTPUT inserted.ID -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.5.6. The DELETE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DELETE statement removes records from a database table. DELETE statements are only possible on single tables. Support for multi-table deletes might be implemented in the future. An example delete query is given here:
DELETE AUTHOR WHERE ID = 100;
create.delete(AUTHOR) .where(AUTHOR.ID.eq(100)) .execute();
The following subsections discuss the various subclauses of the DELETE
statement.
4.5.6.1. DELETE .. USING
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The USING
clause allows for a JOIN
between the table from which to delete rows with other tables.
Dialect support
This example using jOOQ:
deleteFrom(BOOK).using(AUTHOR).where(BOOK.AUTHOR_ID.eq(AUTHOR.ID)).and(AUTHOR.LAST_NAME.eq("Poe"))
Translates to the following dialect specific expressions:
-- ASE, ORACLE, SQLSERVER, SYBASE DELETE FROM BOOK FROM AUTHOR WHERE ( BOOK.AUTHOR_ID = AUTHOR.ID AND AUTHOR.LAST_NAME = 'Poe' ) -- AURORA_MYSQL, MARIADB, MYSQL DELETE FROM BOOK USING BOOK, AUTHOR WHERE ( BOOK.AUTHOR_ID = AUTHOR.ID AND AUTHOR.LAST_NAME = 'Poe' ) -- AURORA_POSTGRES, COCKROACHDB, POSTGRES, REDSHIFT, SNOWFLAKE DELETE FROM BOOK USING AUTHOR WHERE ( BOOK.AUTHOR_ID = AUTHOR.ID AND AUTHOR.LAST_NAME = 'Poe' ) -- TERADATA DELETE BOOK FROM AUTHOR WHERE ( BOOK.AUTHOR_ID = AUTHOR.ID AND AUTHOR.LAST_NAME = 'Poe' ) -- ACCESS, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MEMSQL, SQLDATAWAREHOUSE, SQLITE, -- TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.5.6.2. DELETE .. WHERE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The WHERE
clause allows for adding a conditional expressions to the DELETE
statement, which restricts the rows to be deleted.
Dialect support
This example using jOOQ:
deleteFrom(BOOK).where(BOOK.ID.in(1, 2, 3))
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, -- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, -- TERADATA, TRINO, VERTICA, YUGABYTEDB DELETE FROM BOOK WHERE BOOK.ID IN ( 1, 2, 3 ) -- BIGQUERY DELETE FROM BOOK WHERE ( BOOK.ID IN ( 1, 2, 3 ) AND TRUE )
4.5.6.3. DELETE .. ORDER BY .. LIMIT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ORDER BY
and LIMIT
clauses allow for deleting only a subset of the data in a table, based on their ordering. This can be useful to implement queue semantics, e.g. to delete only the top row, and possibly return it in one go.
Dialect support
This example using jOOQ:
deleteFrom(BOOK).orderBy(BOOK.ID.asc()).limit(1)
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, COCKROACHDB, DB2, MARIADB, MYSQL, TRINO DELETE FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 -- AURORA_POSTGRES, DUCKDB, EXASOL, HANA, HSQLDB, REDSHIFT, SNOWFLAKE, SQLITE, VERTICA, YUGABYTEDB DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) -- BIGQUERY DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK WHERE TRUE ORDER BY BOOK.ID ASC LIMIT 1 ) -- DERBY, H2, ORACLE, POSTGRES DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC FETCH NEXT 1 ROWS ONLY ) -- FIREBIRD DELETE FROM BOOK ORDER BY BOOK.ID ASC ROWS 1 -- INFORMIX DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT * FROM ( SELECT FIRST 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) x ) -- MEMSQL DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT * FROM ( SELECT BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC LIMIT 1 ) t ) -- SQLDATAWAREHOUSE, SQLSERVER, SYBASE DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) -- TERADATA DELETE FROM BOOK WHERE BOOK.ID IN ( SELECT * FROM ( SELECT TOP 1 BOOK.ID FROM BOOK ORDER BY BOOK.ID ASC ) x ) -- ACCESS, ASE /* UNSUPPORTED */
4.5.6.4. DELETE .. RETURNING
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The RETURNING
clause allows for returning expressions based on the deleted rows.
Dialect support
This example using jOOQ:
deleteFrom(BOOK).where(BOOK.ID.eq(1)).returningResult(BOOK.TITLE)
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, FIREBIRD, POSTGRES, SQLITE, YUGABYTEDB DELETE FROM BOOK WHERE BOOK.ID = 1 RETURNING BOOK.TITLE -- DB2, H2 SELECT TITLE FROM OLD TABLE ( DELETE FROM BOOK WHERE BOOK.ID = 1 ) BOOK -- MARIADB DELETE FROM BOOK WHERE BOOK.ID = 1 RETURNING TITLE -- ORACLE DECLARE o0 DBMS_SQL.VARCHAR2_TABLE; c0 sys_refcursor; BEGIN DELETE FROM BOOK WHERE BOOK.ID = 1 RETURNING BOOK.TITLE BULK COLLECT INTO o0; ? := SQL%ROWCOUNT; OPEN c0 FOR SELECT * FROM TABLE(o0); ? := c0; END; -- SQLSERVER DELETE FROM BOOK OUTPUT deleted.TITLE WHERE BOOK.ID = 1 -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, HANA, HSQLDB, INFORMIX, MEMSQL, MYSQL, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.5.7. The MERGE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The MERGE statement is one of the most advanced standardised SQL constructs, which is supported by DB2, HSQLDB, Oracle, SQL Server and Sybase (MySQL has the similar INSERT .. ON DUPLICATE KEY UPDATE construct)
The point of the standard MERGE statement is to take a TARGET table, and merge (INSERT, UPDATE) data from a SOURCE table into it. DB2, Oracle, SQL Server and Sybase also allow for DELETING some data and for adding many additional clauses. With jOOQ 3.17.16, 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();
Typesafety of VALUES() for degrees up to 22
Much like the INSERT statement, the MERGE
statement's VALUES()
clause provides typesafety for degrees up to 22, in both the standard syntax variant as well as the H2 variant.
4.6. SQL Statements (DDL)
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The Data Definition Language (DDL) is used to CREATE, ALTER, and DROP various object types in the database catalog. jOOQ supports an increasing number of these operations natively, and also adds synthetic operation support for convenience.
While many DDL statements are supported natively, and have a 1:1 correspondence to the jOOQ API's representation, dialects differ in many subtle ways when it comes to DDL statement support. These differences may include:
- Different keywords to mean the same thing. For example, the keywords
ALTER
,CHANGE
, orMODIFY
may be used when altering columns or other attributes in a table. - Different statements instead of subclauses. For example, some dialects may choose to support
RENAME [object type] .. TO ..
statements instead of making the rename operation a subclause ofALTER [object type] .. RENAME TO ..
- Some syntax may not be supported, or not be supported consistently, such as the various
IF EXISTS
andIF NOT EXISTS
clauses. Emulations are possible using the dialect's procedural language
Because of these many differences, the jOOQ manual will not list each individual native SQL representation of each jOOQ API call. Also, some optional clauses may exist, such as the IF EXISTS
or OR REPLACE
clauses, which can easily be discovered from the API. The manual will omit documenting these clauses in every example.
Commercial support for emulations
A lot of DDL queries come with syntax that requires emulation using anonymous blocks. While basic anonymous blocks are supported in the jOOQ Open Source Edition as well, more sophisticated blocks and other procedural logic is a commercial only feature.
4.6.1. The ALTER statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
ALTER
statements are used to alter properties of existing objects in the database catalog.
4.6.1.1. ALTER DATABASE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The only property of a database that can be changed, currently, is its name. In order to alter an database's name, use:
// Renaming the database create.alterDatabase("old_database").renameTo("new_database").execute();
Dialect support
This example using jOOQ:
alterDatabase("d").renameTo("e")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, POSTGRES, YUGABYTEDB ALTER DATABASE d RENAME TO e -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
IF EXISTS
A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS
clause:
// Renaming the database create.alterDatabaseIfExists("old_database").renameTo("new_database").execute();
Dialect support
This example using jOOQ:
alterDatabaseIfExists("d").renameTo("e")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, POSTGRES, YUGABYTEDB DO $$ BEGIN ALTER DATABASE d RENAME TO e; EXCEPTION WHEN SQLSTATE '3D000' THEN NULL; END $$ -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, -- MARIADB, MEMSQL, MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.1.2. ALTER DOMAIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ALTER DOMAIN
statement allows for altering DOMAIN types for use as data types in table columns.
// Alter the default of a domain create.alterDomain("d").setDefault(1).execute(); create.alterDomain("d").dropDefault().execute(); // Alter the NOT NULL constraint of a domain create.alterDomain("d").setNotNull().execute(); create.alterDomain("d").dropNotNull().execute(); // Add / remove CHECK constraints to a domain create.alterDomain("d").add(constraint("c").check(value(INTEGER).gt(0))).execute(); create.alterDomain("d").dropConstraint("c").execute(); // Rename the domain create.alterDomain("d").renameTo("e").execute(); // Rename a constraint create.alterDomain("d").renameConstraint("c1").to("c1").execute();
4.6.1.3. ALTER INDEX
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The only property of an index that can be changed, currently, is its name. In order to alter an index's name, use:
// Renaming the index create.alterIndex("old_index").renameTo("new_index").execute();
Dialect support
This example using jOOQ:
alterIndex("i").renameTo("j")
Translates to the following dialect specific expressions:
-- ASE EXEC sp_rename 'i', j, 'index' -- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL ALTER TABLE RENAME INDEX i TO j -- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, ORACLE, POSTGRES ALTER INDEX iRENAME TO j -- DB2, DERBY, HANA RENAME INDEX iTO j -- SQLDATAWAREHOUSE, SQLSERVER EXEC sp_rename 'i', j, 'INDEX' -- ACCESS, BIGQUERY, DUCKDB, EXASOL, FIREBIRD, INFORMIX, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, -- YUGABYTEDB /* UNSUPPORTED */
IF EXISTS
A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS
clause:
// Renaming the index create.alterIndexIfExists("old_index").renameTo("new_index").execute();
Dialect support
This example using jOOQ:
alterIndexIfExists("i").renameTo("j")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, POSTGRES ALTER INDEX IF EXISTS iRENAME TO j -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' RENAME INDEX iTO j '; END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 259 BEGIN END; EXECUTE IMMEDIATE ' RENAME INDEX iTO j '; END; -- MARIADB BEGIN NOT ATOMIC DECLARE CONTINUE HANDLER FOR SQLSTATE '42000' BEGIN END; DECLARE CONTINUE HANDLER FOR SQLSTATE '42S02' BEGIN END; ALTER TABLE RENAME INDEX i TO j; END -- MYSQL CREATE PROCEDURE block_1700915565455_1702396() MODIFIES SQL DATA BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42000' BEGIN END; ALTER TABLE RENAME INDEX i TO j; END; CALL block_1700915565455_1702396(); DROP PROCEDURE block_1700915565455_1702396; -- ORACLE BEGIN EXECUTE IMMEDIATE ' ALTER INDEX iRENAME TO j '; EXCEPTION WHEN others THEN IF sqlerrm LIKE 'ORA-01418%' THEN NULL; ELSE RAISE; END IF; END; -- SQLDATAWAREHOUSE BEGIN TRY EXEC sp_rename 'i', j, 'INDEX' END TRY BEGIN CATCH IF error_number() != 2714 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLSERVER BEGIN TRY EXEC sp_rename 'i', j, 'INDEX' END TRY BEGIN CATCH IF error_number() != 2714 THROW; END CATCH -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, FIREBIRD, HSQLDB, INFORMIX, MEMSQL, REDSHIFT, SNOWFLAKE, -- SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.1.4. ALTER SCHEMA
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The only property of a schema that can be changed, currently, is its name. In order to alter an schema's name, use:
// Renaming the schema create.alterSchema("old_schema").renameTo("new_schema").execute();
Dialect support
This example using jOOQ:
alterSchema("s").renameTo("t")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, POSTGRES, REDSHIFT, SNOWFLAKE, VERTICA ALTER SCHEMA sRENAME TO t -- HANA RENAME SCHEMA sTO t -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, -- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, YUGABYTEDB /* UNSUPPORTED */
IF EXISTS
A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS
clause:
// Renaming the schema create.alterSchemaIfExists("old_schema").renameTo("new_schema").execute();
Dialect support
This example using jOOQ:
alterSchemaIfExists("s").renameTo("t")
Translates to the following dialect specific expressions:
-- H2, SNOWFLAKE ALTER SCHEMA IF EXISTS sRENAME TO t -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 362 BEGIN END; EXECUTE IMMEDIATE ' RENAME SCHEMA sTO t '; END; -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HSQLDB, -- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, -- VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.1.5. ALTER SEQUENCE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The following types of statements are supported when altering a sequence:
Alter sequence properties
jOOQ supports a variety of sequence properties through meta data and DDL.
// Cache a number of values for the sequence, typically on a per session basis. create.alterSequence("sequence").cache(200).execute(); create.alterSequence("sequence").noCache().execute(); // Specify whether the sequence should cycle when it reaches the MAXVALUE create.alterSequence("sequence").cycle().execute(); create.alterSequence("sequence").noCycle().execute(); // The increment by which a sequence should produce the next value create.alterSequence("sequence").incrementBy(10).execute(); // The MAXVALUE before which the sequence should cycle if applicable create.alterSequence("sequence").maxvalue(1000).execute(); create.alterSequence("sequence").noMaxvalue.execute(); // The MINVALUE from which the sequence should cycle if applicable create.alterSequence("sequence").minvalue(1).execute(); create.alterSequence("sequence").noMinvalue.execute(); // Let the sequence restart with MINVALUE or with a specific value create.alterSequence(S_AUTHOR_ID).restart().execute(); create.alterSequence(S_AUTHOR_ID).restartWith(1).execute(); // Let the sequence start with a specific value create.alterSequence(S_AUTHOR_ID).startWith(1).execute();
RENAME
Like most object types, sequences can be renamed:
// Renaming the sequence create.alterSequence("old_sequence").renameTo("new_sequence").execute();
4.6.1.6. ALTER TABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ALTER TABLE
statement is certainly the most powerful among DDL statements, as tables are the most important object type in a database catalog. The following types of statements are supported when altering a table:
ADD
In most dialects, tables can contain two types of objects:
- Columns
- Constraints
These types of objects can be added to a table using the following API:
// Adding a single column to a table create.alterTable("table").add("column", INTEGER).execute(); // Adding several columns to a table in one go create.alterTable("table").add(field(name("column1"), INTEGER), field(name("column2"), INTEGER)).execute(); // Adding an unnamed constraint to a table create.alterTable("table").add(primaryKey("id")).execute(); create.alterTable("table").add(unique("user_name")).execute(); create.alterTable("table").add(foreignKey("author_id").references("author")).execute(); create.alterTable("table").add(check(length(field(name("user_name"), VARCHAR)).gt(5))).execute(); // Adding a named constraint to a table create.alterTable("table").add(constraint("pk").primaryKey("id")).execute(); create.alterTable("table").add(constraint("uk").unique("user_name")).execute(); create.alterTable("table").add(constraint("fk").foreignKey("author_id").references("author")).execute(); create.alterTable("table").add(constraint("ck").check(length(field(name("user_name"), VARCHAR)).gt(5))).execute();
There exists alternative API representing optional keywords, such as e.g. addColumn()
, which have been omitted from the examples.
It is possible to specify the column ordering when adding new columns, where this is supported:
// Adding a single column and specify its position create.alterTable("table").add("column", INTEGER).after("other_column").execute(); create.alterTable("table").add("column", INTEGER).before("other_column").execute(); create.alterTable("table").add("column", INTEGER).first().execute();
Note that some dialects also consider indexes to be a part of a table, but jOOQ does not yet support ALTER TABLE
subclauses modifying indexes. Consider CREATE INDEX, ALTER INDEX, or DROP INDEX, instead.
ALTER
Both of the above objects can be altered in a table using the following API:
// Specify a new default value for a column create.alterTable("table").alter("column").default_(1).execute(); create.alterTable("table").alter("column").dropDefault().execute(); // Specify the not null constraint on a column create.alterTable("table").alter("column").setNotNull().execute(); create.alterTable("table").alter("column").dropNotNull().execute(); // Set a new data type on the column create.alterTable("table").alter("column").set(VARCHAR(50)).execute(); // Set the enforced flag on a constraint create.alterTable("table").alterConstraint("uk").enforced().execute(); create.alterTable("table").alterConstraint("uk").notEnforced().execute();
There exists alternative API representing optional keywords, such as e.g. alterColumn()
, which have been omitted from the examples.
COMMENT
For convenience, jOOQ supports MySQL's COMMENT
syntax also on ALTER TABLE
, which corresponds to the more standard COMMENT ON TABLE statement
// Specify a new comment on a table create.alterTable("table").comment("a comment describing the table").execute();
DROP
Both columns and constraints can also be dropped from tables using this API:
// Drop a single column create.alterTable("table").drop("column").execute(); // Drop several columns in one go create.alterTable("table").drop("column1", "column2").execute(); // Add CASCADE or RESTRICT clauses when dropping columns (or constraints) create.alterTable("table").drop("column").cascade().execute(); create.alterTable("table").drop("column").restrict().execute(); // Drop a constraint create.alterTable("table").dropConstraint("uk").execute(); // Drop specific types of constraints (e.g. if the above syntax is not supported by the dialect) create.alterTable("table").dropPrimaryKey().execute(); create.alterTable("table").dropUnique("uk").execute(); create.alterTable("table").dropForeignKey("fk").execute();
RENAME
Like most object types, tables, columns, and constraints can be renamed:
// Rename a table create.alterTable("old_table").renameTo("new_table").execute(); // Rename a column create.alterTable("table").renameColumn("old_column").to("new_column").execute(); // Rename a constraint create.alterTable("table").renameConstraint("old_constraint").to("new_constraint").execute(); // Rename a index (as a convenience for the ALTER INDEX statement) create.alterTable("table").renameIndex("old_index").to("new_index").execute();
4.6.1.7. ALTER TYPE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ALTER TYPE
statement allows of altering existing types. It supports the following subclauses:
4.6.1.7.1. ALTER TYPE .. RENAME
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Like most object types, types can be renamed. This is independent of the object type:
// Renaming the type create.alterType("old_type").renameTo("new_type").execute();
Dialect support
This example using jOOQ:
alterType("old").renameTo("new")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, POSTGRES ALTER TYPE old RENAME TO new -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.1.7.2. ALTER TYPE .. for enum alterations
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some alterations are specific to enum types, e.g. in PostgreSQL. These include:
// Adding an enum value to an existing type create.alterType("type").addValue("new_enum_value").execute(); // Renaming an enum value of an existing type to a new value create.alterType("type").renameValue("old_enum_value").to("new_enum_value").execute(); // Move an enum type to a new schema create.alterType("type").setSchema("new_schema").execute();
4.6.1.8. ALTER VIEW
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The ALTER VIEW
statement allows of altering existing views. It supports the following subclauses:
4.6.1.8.1. ALTER VIEW .. COMMENT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement allows for changing the comment associated with a view. It is an alias for the COMMENT ON VIEW statement
Dialect support
This example using jOOQ:
alterView("v").comment("new comment")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, FIREBIRD, POSTGRES, TERADATA, TRINO, VERTICA, YUGABYTEDB COMMENT ON VIEW v IS 'new comment' -- BIGQUERY ALTER VIEW v SET OPTIONS (DESCRIPTION = 'new comment') -- DB2, H2, HSQLDB, ORACLE COMMENT ON TABLE v IS 'new comment' -- SNOWFLAKE ALTER VIEW v SET COMMENT = 'new comment' -- SQLSERVER BEGIN TRY DECLARE @u varchar(max) = schema_name(); EXEC sp_addextendedproperty 'MS_Description', 'new comment', 'schema', @u, 'view', 'v', DEFAULT, DEFAULT END TRY BEGIN CATCH EXEC sp_updateextendedproperty 'MS_Description', 'new comment', 'schema', @u, 'view', 'v', DEFAULT, DEFAULT END CATCH -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, EXASOL, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, -- SQLDATAWAREHOUSE, SQLITE, SYBASE /* UNSUPPORTED */
4.6.1.8.2. ALTER VIEW .. RENAME
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement allows for renaming a view.
Dialect support
This example using jOOQ:
alterView("v").renameTo("new_name")
Translates to the following dialect specific expressions:
-- ASE, SQLSERVER EXEC sp_rename v, new_name -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, POSTGRES, SNOWFLAKE, TRINO, VERTICA ALTER VIEW v RENAME TO new_name -- EXASOL, TERADATA RENAME VIEW v TO new_name -- HSQLDB, YUGABYTEDB ALTER TABLE v RENAME TO new_name -- ORACLE RENAME v TO new_name -- ACCESS, AURORA_MYSQL, BIGQUERY, DB2, DERBY, FIREBIRD, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, -- SQLDATAWAREHOUSE, SQLITE, SYBASE /* UNSUPPORTED */
4.6.1.8.3. ALTER VIEW IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A popular subclause of DDL statements that jOOQ can usually emulate, is the IF EXISTS
clause:
Dialect support
This example using jOOQ:
alterViewIfExists("v").renameTo("new_name")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, POSTGRES ALTER VIEW IF EXISTS v RENAME TO new_name -- ORACLE BEGIN EXECUTE IMMEDIATE ' RENAME v TO new_name '; EXCEPTION WHEN others THEN IF sqlerrm LIKE 'ORA-00942%' THEN NULL; ELSIF sqlerrm LIKE 'ORA-04043%' THEN NULL; ELSE RAISE; END IF; END; -- SNOWFLAKE ALTER VIEW v RENAME TO new_name -- SQLSERVER BEGIN TRY EXEC sp_rename v, new_name END TRY BEGIN CATCH IF error_number() != 15225 THROW; END CATCH -- YUGABYTEDB ALTER TABLE IF EXISTS v RENAME TO new_name -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, -- REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.2. The COMMENT statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The COMMENT
statement can be used to store a description for an object from the database catalog.
It is available for the following types of object:
4.6.2.1. COMMENT ON TABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to comment on a table.
Dialect support
This example using jOOQ:
commentOnTable("table").is("the comment")
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL ALTER TABLE table COMMENT = 'the comment' -- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, ORACLE, POSTGRES, TERADATA, TRINO, VERTICA, -- YUGABYTEDB COMMENT ON TABLE table IS 'the comment' -- BIGQUERY ALTER TABLE table SET OPTIONS (DESCRIPTION = 'the comment') -- SNOWFLAKE ALTER TABLE table SET COMMENT = 'the comment' -- SQLSERVER BEGIN TRY DECLARE @u varchar(max) = schema_name(); EXEC sp_addextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'table', 'table', DEFAULT, DEFAULT END TRY BEGIN CATCH EXEC sp_updateextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'table', 'table', DEFAULT, DEFAULT END CATCH -- ACCESS, ASE, DERBY, DUCKDB, INFORMIX, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SYBASE /* UNSUPPORTED */
4.6.2.2. COMMENT ON VIEW
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to comment on a view.
Dialect support
This example using jOOQ:
commentOnView("view").is("the comment")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, FIREBIRD, HANA, POSTGRES, TERADATA, TRINO, VERTICA, YUGABYTEDB COMMENT ON VIEW view IS 'the comment' -- BIGQUERY ALTER VIEW view SET OPTIONS (DESCRIPTION = 'the comment') -- DB2, H2, HSQLDB, ORACLE COMMENT ON TABLE view IS 'the comment' -- SNOWFLAKE ALTER VIEW view SET COMMENT = 'the comment' -- SQLSERVER BEGIN TRY DECLARE @u varchar(max) = schema_name(); EXEC sp_addextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'view', 'view', DEFAULT, DEFAULT END TRY BEGIN CATCH EXEC sp_updateextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'view', 'view', DEFAULT, DEFAULT END CATCH -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, EXASOL, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, -- SQLDATAWAREHOUSE, SQLITE, SYBASE /* UNSUPPORTED */
4.6.2.3. COMMENT ON COLUMN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to comment on a column.
Dialect support
This example using jOOQ:
commentOnColumn(name("table", "column")).is("the comment")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DB2, EXASOL, FIREBIRD, H2, HANA, HSQLDB, ORACLE, POSTGRES, TERADATA, TRINO, VERTICA, -- YUGABYTEDB COMMENT ON COLUMN table.column IS 'the comment' -- SNOWFLAKE ALTER TABLE table ALTER COLUMN column COMMENT 'the comment' -- SQLSERVER BEGIN TRY DECLARE @u varchar(max) = schema_name(); EXEC sp_addextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'table', 'table', 'column', 'column' END TRY BEGIN CATCH EXEC sp_updateextendedproperty 'MS_Description', 'the comment', 'schema', @u, 'table', 'table', 'column', 'column' END CATCH -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, -- SQLITE, SYBASE /* UNSUPPORTED */
4.6.3. The CREATE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE
statement is the most important DDL statement. It allows for creating new objects in the database catalog.
4.6.3.1. CREATE DATABASE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE DATABASE
statement is used to create a new database (catalog).
// Create a database create.createDatabase("new_database").execute();
Dialect support
This example using jOOQ:
createDatabase("d")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, MARIADB, MEMSQL, MYSQL, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, YUGABYTEDB CREATE DATABASE d -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, ORACLE, -- REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.3.2. CREATE DOMAIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE DOMAIN
statement allows for creating DOMAIN types for use as data types in table columns.
Depending on the dialect, a DOMAIN
combines the following features:
- A qualified name
- A base data type
- A
DEFAULT
value - A
NOT NULL
constraint - A
COLLATION
- A set of
CHECK
constraints
Domains can be created in jOOQ using:
// Create a domain on a base type create.createDomain("d1").as(INTEGER).execute(); // Create a domain on a base type and add a DEFAULT expression create.createDomain("d2").as(INTEGER).default_(1).execute(); // Create a domain on a base type and add a CHECK constraint create.createDomain("d3").as(INTEGER).constraints(check(value(INTEGER).gt(0))).execute();
Dialect support
This example using jOOQ:
createDomain("d").as(INTEGER)
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, H2, HSQLDB, POSTGRES, YUGABYTEDB CREATE DOMAIN d AS int -- FIREBIRD CREATE DOMAIN d AS integer -- ORACLE CREATE DOMAIN d AS number(10) -- SQLSERVER CREATE TYPE d FROM int -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, -- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.3.3. CREATE FUNCTION
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE FUNCTION
statement allows for creating stored functions in your catalog.
A stored function, as opposed to a stored procedure, can be used in SQL statements as a scalar column expression, specifically a user defined function, or as a table expression, specifically a table valued functions.
4.6.3.3.1. Scalar functions
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The most common type of user defined function is a scalar function, i.e. a function that returns a single scalar value. Such functions can be used in the SELECT clause, the WHERE clause, the GROUP BY clause, the HAVING clause, the ORDER BY clause, and elsewhere, where column expressions can be used.
A simple example for creating such a function is:
// Create a function that always return 1 create.createFunction("one") .returns(INTEGER) .as(return_(1)) .execute(); // Create a function that returns the sum of its inputs Parameter<Integer> i1 = in("i1", INTEGER); Parameter<Integer> i2 = in("i2", INTEGER); create.createFunction("my_sum") .parameters(i1, i2) .returns(INTEGER) .as(return_(i1.plus(i2))) .execute();
Once you've created the above functions, you can either run code generation to get a type safe stub for calling them, or use plain SQL (specifically, DSL.function()) from within a SELECT statement:
// Call the previously created functions with generated code: create.select(one(), mySum(1, 2)).fetchOne(); // ...or with plain SQL create.select( function(name("one"), INTEGER), function(name("my_sum"), INTEGER, val(1), val(2)) ).fetchOne();
Both yielding:
+-----+--------+ | ONE | MY_SUM | +-----+--------+ | 1 | 3 | +-----+--------+
4.6.3.3.2. CREATE OR REPLACE FUNCTION
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In most cases, you will want to CREATE OR REPLACE
a function, not CREATE [ OR FAIL ]
when the function already exists. For this, just use the auxiliary OR REPLACE
clause, which can be emulated by jOOQ via an additional DROP FUNCTION statement if this syntax is not available in your dialect.
// Create a function that always return 1 create.createOrReplaceFunction("one") .returns(INTEGER) .as(return_(1)) .execute();
4.6.3.3.3. SQL data access characteristics
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some dialects require the explicit specification of a few characteristics of a function, defining what kind of content a function is allowed (and expected) to have. These act both as contracts for your development (similar to the java.lang.FunctionalInterface
annotation), as well as hints to the database regarding whether a function is expected to have side-effects (and thus maybe cannot be used in a SELECT statement), or whether it depends on data, or is purely deterministic (see also the DETERMINISTIC characteristic). The SQL data access characteristics include:
-
NO SQL
-
CONTAINS SQL
-
READS SQL DATA
-
MODIFIES SQL DATA
While the semantics seem pretty clear, please refer to your database manual for the details, as there may be subtle differences, e.g. regarding what particular procedural statement constitues "SQL".
If a characteristic is not supported by your dialect, you can still specify it, and jOOQ will simply ignore it in generated SQL.
create.createFunction("f1").returns(INTEGER).noSQL().as(return_(1)).execute(); create.createFunction("f2").returns(INTEGER).containsSQL().as(return_(select(val(1)))).execute(); create.createFunction("f3").returns(INTEGER).readsSQLData().as(return_(selectCount().from(BOOK))).execute(); create.createFunction("f4").returns(INTEGER).modifiesSQLData().as( insertInto(LOGS).columns(LOGS.TEXT).values("Function F4 was called"), return_(1) ).execute();
This works just like SQL data access characteristics for procedures
4.6.3.3.4. DETERMINISTIC characteristic
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some dialects require the explicit specification of a few characteristics of a function. The DETERMINISTIC
characteristic can be used to tell the database that contents of a function are guaranteed by the user to be "deterministic" (or "IMMUTABLE
" in PostgreSQL), meaning that the result of a function is purely defined by the function arguments (never by data or session values or the current time or random number generators, etc.) such that a function expression can be replaced by the result value at the call site. Such a function is also said to be side-effect free, and pure. Some dialects (e.g. Oracle) allow for using DETERMINISTIC
functions in function based indexes.
If DETERMINISTIC
is not supported by your dialect, you can still specify it, and jOOQ will simply ignore it in generated SQL.
create.createFunction("f1").returns(INTEGER).deterministic().as(return_(1)).execute(); create.createFunction("f2").returns(INTEGER).notDeterministic().as(return_(rand())).execute();
4.6.3.3.5. ON NULL INPUT characteristic
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This characteristic both determines a contract for use by optimisers, as well as influences the behaviour of a function.
Most built-in SQL functions return NULL
as soon as any of the arguments are NULL
. For example SUBSTRING:
create.select( substring("abc" , 2) .as("s1"), substring("abc" , val(null, INTEGER)).as("s2"), substring(val(null, VARCHAR), 2) .as("s3"), substring(val(null, VARCHAR), val(null, INTEGER)).as("s4"), ).fetchOne();
Yielding:
+----+--------+--------+--------+ | s1 | s2 | s3 | s4 | +----+--------+--------+--------+ | bc | {null} | {null} | {null} | +----+--------+--------+--------+
While it is easy to implement this manually, it is both convenient, and helpful for optimisers, to just use the characteristic to achieve this standard behaviour, and possibly even to prevent calling the function, preventing the overhead from the context switches, etc.
If not natively supported by your dialect, jOOQ will simply wrap your function body in a IF statement checking for argument value nullability.
Parameter<Integer> i1 = in("i1", INTEGER); Parameter<Integer> i2 = in("i2", INTEGER); // The function always returns NULL if any argument value is NULL create.createFunction("my_sum") .parameters(i1, i2) .returns(INTEGER) .returnsNullOnNullInput() .as(return_(i1.plus(i2))) .execute(); // The function may not return NULL if any argument value is NULL create.createFunction("my_null_safe_sum") .parameters(i1, i2) .returns(INTEGER) .calledOnNullInput() .as(return_(coalesce(i1, 0).plus(coalesce(i2, 0)))) .execute();
4.6.3.4. CREATE INDEX
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE INDEX
statement allows for creating indexes on table columns.
CREATE INDEX
In its simplest form, the statement can be used like this:
// Create an index on a single column create.createIndex("index").on("table", "column").execute(); // Create an index on several columns create.createIndex("index").on("table", "column1", "column2").execute();
CREATE UNIQUE INDEX
In many dialects, there is a possibility of creating a unique index, which acts like a constraint (see ALTER TABLE or CREATE TABLE), but is not really a constraint. Most dialects will create an index automatically to enforce a UNIQUE
constraint, so using a constraint instead may seem a bit cleaner. A UNIQUE INDEX
is created like this:
// Create an index on a single column create.createUniqueIndex("index").on("table", "column").execute(); // Create an index on several columns create.createUniqueIndex("index").on("table", "column1", "column2").execute();
Sorted indexes
In most dialects, indexes have their columns sorted ascendingly by default. If you wish to create an index with a differing sort order, you can do so by providing the order explicitly:
// Create a sorted index on several columns create.createIndex("index").on( table(name("table")), field(name("column1")).asc(), field(name("column2")).desc() ).execute();
Covering indexes (with INCLUDE clause)
A few dialects support an INCLUDE
clause when creating an index. This can be useful to create covering indexes. These are indexes that "cover" the needs of an entire query, such that no secondary lookup needs to be done in a heap table or clustered index, after finding only parts of the projection in the index data structure. The data from the columns of the INCLUDE
clause will be located only in the index leaf nodes (useful for projections), not in the index tree structure (useful for searches), which reduces index maintenance overhead, and index size.
If a dialect does not support this clause, jOOQ will simply add the INCLUDE
columns into the ordinary index column list.
// Create a covering index with included columns create.createIndex("index").on("table", "search_column").include("projection_column").execute();
Partial indexes (with WHERE clause)
A few dialects support a WHERE
clause when creating an index. This is very useful to drastically reduce the size of an index, and thus index maintenance, if only parts of the data of a column need to be included in the index.
// Create a partial index create.createIndex("index").on("table", "column").where(field(name("column")).gt(0)).execute();
4.6.3.5. CREATE PROCEDURE
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE PROCEDURE
statement allows for creating stored procedures in your catalog.
A stored procedure, as opposed to a stored function, is expected to have side effects of some sort, and can thus not be used in SQL statements.
A simple example for creating such a procedure is:
// Create a procedure that inserts a log message in a table create.createProcedure("log") .as(insertInto(LOG).columns(LOG.TEXT).values("Log called")) .execute();
Once you've created the above procedure, you can either run code generation to get a type safe stub for calling them, or use CALL in an anonymous block, or directly:
// Call the previously created procedure with generated code: log(configuration); // ...or with the CALL statement in an anonymous block create.begin(call(name("log"))).execute(); // ...or with the CALL statement directly call(name("log")).execute();
4.6.3.5.1. CREATE OR REPLACE PROCEDURE
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In most cases, you will want to CREATE OR REPLACE
a procedure, not CREATE [ OR FAIL ]
when the procedure already exists. For this, just use the auxiliary OR REPLACE
clause, which can be emulated by jOOQ via an additional DROP PROCEDURE statement if this syntax is not available in your dialect.
// Create a procedure that inserts a log message in a table create.createOrReplaceProcedure("log") .as(insertInto(LOG).columns(LOG.TEXT).values("Log called")) .execute();
4.6.3.5.2. SQL data access characteristics
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some dialects require the explicit specification of a few characteristics of a procedure, defining what kind of content a procedure is allowed (and expected) to have. These act both as contracts for your development (similar to the java.lang.FunctionalInterface
annotation), as well as hints to the database regarding whether a procedure is expected to have side-effects (and thus maybe cannot be used indirectly via a stored function in a SELECT statement), or whether it depends on data, or is purely deterministic. The SQL data access characteristics include:
While procedures are generally expected to yield side effects, it may be useful to use a procedure as a "function with quirky syntax" to be consumed by other functions, because it can return several OUT
parameters, instead of just a single RETURN
value, like function, hence the utility of these characteristics also in procedures.
-
NO SQL
-
CONTAINS SQL
-
READS SQL DATA
-
MODIFIES SQL DATA
While the semantics seem pretty clear, please refer to your database manual for the details, as there may be subtle differences, e.g. regarding what particular procedural statement constitues "SQL".
If a characteristic is not supported by your dialect, you can still specify it, and jOOQ will simply ignore it in generated SQL.
Parameter<Integer> o = out("o", INTEGER); create.createProcedure("p1") .parameters(o) .noSQL() .as(o.set(1)) .execute(); create.createProcedure("p2") .parameters(o) .containsSQL() .as(o.set(select(val(1)))) .execute(); create.createProcedure("p3") .parameters(o) .readsSQLData() .as(o.set(selectCount().from(BOOK))) .execute(); create.createProcedure("p4") .parameters(o) .modifiesSQLData() .as( insertInto(LOGS).columns(LOGS.TEXT).values("Function F4 was called"), o.set(1) ) .execute();
This works just like SQL data access characteristics for functions
4.6.3.6. CREATE SCHEMA
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE SCHEMA
statement is used to create a new schema in the database catalog.
// Create a schema create.createSchema("new_schema").execute();
Dialect support
This example using jOOQ:
createSchema("s")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, -- SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB CREATE SCHEMA s -- ORACLE CREATE USER s NO AUTHENTICATION QUOTA UNLIMITED ON USERS -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO /* UNSUPPORTED */
4.6.3.7. CREATE SEQUENCE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The CREATE SEQUENCE
statement is used to create a new sequence in the database catalog.
// Create a sequence with default flags create.createSequence("sequence").execute();
Sequence flags
Many dialects support standard SQL sequence flag in CREATE SEQUENCE
and also ALTER SEQUENCE statements:
All of these flags can be combined in a single CREATE SEQUENCE
statement.
// Cache a number of values for the sequence, typically on a per session basis. create.createSequence("sequence").cache(200).execute(); create.createSequence("sequence").noCache().execute(); // Specify whether the sequence should cycle when it reaches the MAXVALUE create.createSequence("sequence").cycle().execute(); create.createSequence("sequence").noCycle().execute(); // The increment by which a sequence should produce the next value create.createSequence("sequence").incrementBy(10).execute(); // The MAXVALUE before which the sequence should cycle if applicable create.createSequence("sequence").maxvalue(1000).execute(); create.createSequence("sequence").noMaxvalue.execute(); // The MINVALUE from which the sequence should cycle if applicable create.createSequence("sequence").minvalue(1).execute(); create.createSequence("sequence").noMinvalue.execute(); // Let the sequence start with a specific value create.createSequence(S_AUTHOR_ID).startWith(1).execute();
4.6.3.8. CREATE TABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Arguably the most used DDL statement is the CREATE TABLE
statement.
The following subsections discuss various usages of CREATE TABLE
, as well as the relevant bits of meta data that can be added to a table.
4.6.3.8.1. Columns
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
All tables contain at least one column (except for some esoteric cases in PostgreSQL), and all SQL dialects support creating such tables:
// Create a new table with a column create.createTable("table") .column("col1", INTEGER) .execute();
Dialect support
This example using jOOQ:
createTable("table").column("col1", INTEGER)
Translates to the following dialect specific expressions:
-- ACCESS, DB2, FIREBIRD, HANA, INFORMIX, TERADATA CREATE TABLE table ( col1 integer ) -- ASE, SYBASE CREATE TABLE table ( col1 int NULL ) -- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, -- SQLDATAWAREHOUSE, SQLSERVER, TRINO, VERTICA, YUGABYTEDB CREATE TABLE table ( col1 int ) -- BIGQUERY CREATE TABLE table ( col1 int64 ) -- COCKROACHDB CREATE TABLE table ( col1 int4 ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( col1 number(10) ) -- SQLITE CREATE TABLE "table" ( col1 int )
4.6.3.8.2. Nullability
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Nullability is a property of a data type, and as such can be attached to the data type using various methods. The default nullability is RDBMS specific, so if you want to be vendor agnostic about nullability in your DDL, better always state it explicitly, for example:
// Specify nullability on columns create.createTable("table") .column("vendor_specific_default", INTEGER) .column("explicit_nullable", INTEGER.null_()) .column("explicit_not_nullable", INTEGER.notNull()) .execute();
Dialect support
This example using jOOQ:
createTable("table") .column("vendor_specific_default", INTEGER) .column("explicit_nullable", INTEGER.null_()) .column("explicit_not_nullable", INTEGER.notNull())
Translates to the following dialect specific expressions:
-- ACCESS, DB2, HANA, INFORMIX, TERADATA CREATE TABLE table ( vendor_specific_default integer, explicit_nullable integer NULL, explicit_not_nullable integer NOT NULL ) -- ASE, SYBASE CREATE TABLE table ( vendor_specific_default int NULL, explicit_nullable int NULL, explicit_not_nullable int NOT NULL ) -- AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, EXASOL, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLSERVER, -- VERTICA, YUGABYTEDB CREATE TABLE table ( vendor_specific_default int, explicit_nullable int NULL, explicit_not_nullable int NOT NULL ) -- BIGQUERY CREATE TABLE table ( vendor_specific_default int64, explicit_nullable int64, explicit_not_nullable int64 NOT NULL ) -- COCKROACHDB CREATE TABLE table ( vendor_specific_default int4, explicit_nullable int4 NULL, explicit_not_nullable int4 NOT NULL ) -- DERBY, H2, HSQLDB CREATE TABLE table ( vendor_specific_default int, explicit_nullable int, explicit_not_nullable int NOT NULL ) -- FIREBIRD CREATE TABLE table ( vendor_specific_default integer, explicit_nullable integer, explicit_not_nullable integer NOT NULL ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( vendor_specific_default number(10), explicit_nullable number(10) NULL, explicit_not_nullable number(10) NOT NULL ) -- SQLITE CREATE TABLE "table" ( vendor_specific_default int, explicit_nullable int NULL, explicit_not_nullable int NOT NULL ) -- TRINO CREATE TABLE table ( vendor_specific_default int, explicit_nullable int, explicit_not_nullable int )
4.6.3.8.3. Defaults
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DEFAULT
expression on a column definition defines what value the column should contain if it is omitted in an INSERT statement, or if an explicit DEFAULT
expression is used in INSERT or UPDATE. By default, this is NULL
in most dialects
// Create a new table with a column with a default expression create.createTable("table") .column("column1", INTEGER.default_(1)) .execute();
To trigger this DEFAULT
expression, you can run this, for example:
// Insert a row using the default expression create.insertInto(table(name("table"))).defaultValues().execute();
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER.default_(1))
Translates to the following dialect specific expressions:
-- ACCESS, DB2, FIREBIRD, HANA, INFORMIX, TERADATA CREATE TABLE table ( column1 integer DEFAULT 1 ) -- ASE CREATE TABLE table ( column1 int DEFAULT 1 NULL ) -- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, -- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB CREATE TABLE table ( column1 int DEFAULT 1 ) -- BIGQUERY CREATE TABLE table ( column1 int64 DEFAULT 1 ) -- COCKROACHDB CREATE TABLE table ( column1 int4 DEFAULT 1 ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( column1 number(10) DEFAULT 1 ) -- SQLITE CREATE TABLE "table" ( column1 int DEFAULT 1 ) -- SYBASE CREATE TABLE table ( column1 int NULL DEFAULT 1 ) -- TRINO /* UNSUPPORTED */
4.6.3.8.4. Identities
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
An IDENTITY
is a special type of DEFAULT on a column, which is computed only on INSERT, and should usually not be replaced by user content. It computes a new value for a surrogate key. Most dialects default to using some system sequence based IDENTITY
, though a UUID
or some other unique value might work as well.
In jOOQ, it is currently only possible to specify whether a column is an IDENTITY
at all, not to influence the value generation algorithm.
// Create a new table with a column with a default expression create.createTable("table") .column("column1", INTEGER.identity(true)) .execute();
Whether an IDENTITY
also needs to be explicitly NOT NULL or a PRIMARY KEY is vendor specific. Ideally, both of these properties are set as well on identities.
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER.identity(true))
Translates to the following dialect specific expressions:
-- ACCESS CREATE TABLE table ( column1 AUTOINCREMENT NOT NULL ) -- ASE, EXASOL CREATE TABLE table ( column1 int IDENTITY NOT NULL ) -- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL CREATE TABLE table ( column1 int NOT NULL AUTO_INCREMENT ) -- AURORA_POSTGRES CREATE TABLE table ( column1 SERIAL4 NOT NULL ) -- COCKROACHDB CREATE TABLE table ( column1 integer DEFAULT (unique_rowid() % 2 ^ 31) NOT NULL ) -- DB2, FIREBIRD CREATE TABLE table ( column1 integer GENERATED BY DEFAULT AS IDENTITY NOT NULL ) -- DERBY, POSTGRES, YUGABYTEDB CREATE TABLE table ( column1 int GENERATED BY DEFAULT AS IDENTITY NOT NULL ) -- H2 CREATE TABLE table ( column1 int NOT NULL GENERATED BY DEFAULT AS IDENTITY ) -- HANA, TERADATA CREATE TABLE table ( column1 integer NOT NULL GENERATED BY DEFAULT AS IDENTITY ) -- HSQLDB CREATE TABLE table ( column1 int GENERATED BY DEFAULT AS IDENTITY(START WITH 1) NOT NULL ) -- INFORMIX CREATE TABLE table ( column1 SERIAL NOT NULL ) -- ORACLE CREATE TABLE table ( column1 number(10) GENERATED BY DEFAULT AS IDENTITY(START WITH 1) NOT NULL ) -- REDSHIFT, SQLDATAWAREHOUSE, SQLSERVER CREATE TABLE table ( column1 int IDENTITY(1, 1) NOT NULL ) -- SNOWFLAKE CREATE TABLE table ( column1 number(10) IDENTITY NOT NULL ) -- SQLITE CREATE TABLE "table" ( column1 integer PRIMARY KEY AUTOINCREMENT NOT NULL ) -- SYBASE CREATE TABLE table ( column1 int NOT NULL IDENTITY ) -- VERTICA CREATE TABLE table ( column1 IDENTITY(1, 1) NOT NULL ) -- BIGQUERY, DUCKDB, TRINO /* UNSUPPORTED */
4.6.3.8.5. Computed columns
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Computed columns, sometimes also called "virtual" columns, are columns that are generated from an expression based on other columns of the same row directly in the database. They cannot be written to, but may be used in projections, filters, and even indexes, as a complement or replacement of function based indexes.
Like any other data type modifying flag, the generator expression can be passed to the data type in jOOQ when creating such a table with computed columns:
Dialect support
This example using jOOQ:
createTable(name("x")) .column(name("interest"), DOUBLE) .column(name("interest_percent"), VARCHAR.generatedAlwaysAs(field(name("interest"), DOUBLE).times(100.0).concat(" %")))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES CREATE TABLE x ( interest double precision, interest_percent varchar GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar) || ' %')) ) -- COCKROACHDB CREATE TABLE x ( interest double precision, interest_percent string GENERATED ALWAYS AS ((CAST((interest * CAST(1E2 AS double precision)) AS string) || ' %')) STORED ) -- DB2, HSQLDB CREATE TABLE x ( interest double, interest_percent varchar(32672) GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar(32672)) || ' %')) ) -- DERBY CREATE TABLE x ( interest double, interest_percent varchar(32672) GENERATED ALWAYS AS ((TRIM(CAST(CAST((interest * 1E2) AS char(38)) AS varchar(32672))) || ' %')) ) -- DUCKDB, HANA CREATE TABLE x ( interest double, interest_percent varchar GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar) || ' %')) ) -- FIREBIRD CREATE TABLE x ( interest double precision, interest_percent varchar(4000) GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar(4000)) || ' %')) ) -- H2 CREATE TABLE x ( interest double, interest_percent varchar AS ((CAST((interest * CAST(1E2 AS double)) AS varchar) || ' %')) ) -- MARIADB, MYSQL CREATE TABLE x ( interest double, interest_percent text GENERATED ALWAYS AS (concat( CAST((interest * 1E2) AS char), ' %' )) ) -- ORACLE CREATE TABLE x ( interest float, interest_percent varchar2(4000) GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar2(4000)) || ' %')) ) -- POSTGRES CREATE TABLE x ( interest double precision, interest_percent varchar GENERATED ALWAYS AS ((CAST((interest * 1E2) AS varchar) || ' %')) STORED ) -- SQLSERVER CREATE TABLE x ( interest float, interest_percent AS (CAST((interest * 1E2) AS varchar(max)) + ' %') ) -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, EXASOL, INFORMIX, MEMSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, -- TERADATA, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.3.8.6. Primary key
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In a normalised database, all tables should have a PRIMARY KEY
. In jOOQ, numerous features are enabled by tables that have one, including for example UpdatableRecords. To create a table with a primary key, write any of these:
// Create a new table with columns and unnamed constraints create.createTable("table") .column("column1", INTEGER) .primaryKey("column1") .execute(); // Equivalent to the above create.createTable("table") .column("column1", INTEGER) .constraints( primaryKey("column1") ) .execute(); // Create a new table with columns and named constraints (recommended if you want to alter the constraint) create.createTable("table") .column("column1", INTEGER) .constraints( constraint("pk").primaryKey("column1") ) .execute();
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER) .constraints( constraint("pk").primaryKey("column1") )
Translates to the following dialect specific expressions:
-- ACCESS, FIREBIRD, HANA CREATE TABLE table ( column1 integer, CONSTRAINT pk PRIMARY KEY (column1) ) -- ASE, SYBASE CREATE TABLE table ( column1 int NULL, CONSTRAINT pk PRIMARY KEY (column1) ) -- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, POSTGRES, REDSHIFT, YUGABYTEDB CREATE TABLE table ( column1 int, CONSTRAINT pk PRIMARY KEY (column1) ) -- BIGQUERY CREATE TABLE table ( column1 int64 ) -- COCKROACHDB CREATE TABLE table ( column1 int4, CONSTRAINT pk PRIMARY KEY (column1) ) -- DB2, TERADATA CREATE TABLE table ( column1 integer NOT NULL, CONSTRAINT pk PRIMARY KEY (column1) ) -- INFORMIX CREATE TABLE table ( column1 integer, PRIMARY KEY (column1) CONSTRAINT pk ) -- MARIADB, MEMSQL, MYSQL, SQLSERVER CREATE TABLE table ( column1 int NOT NULL, CONSTRAINT pk PRIMARY KEY (column1) ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( column1 number(10), CONSTRAINT pk PRIMARY KEY (column1) ) -- SQLDATAWAREHOUSE CREATE TABLE table ( column1 int, CONSTRAINT pk PRIMARY KEY NONCLUSTERED (column1) NOT ENFORCED ) -- SQLITE CREATE TABLE "table" ( column1 int, CONSTRAINT pk PRIMARY KEY (column1) ) -- TRINO CREATE TABLE table ( column1 int ) -- VERTICA CREATE TABLE table ( column1 int, dummy int, CONSTRAINT pk PRIMARY KEY (column1) )
4.6.3.8.7. Unique constraints
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A candidate key that is not ideal for a Primary key should still be declared UNIQUE
to enforce uniqueness, as well as for query performance reasons. In jOOQ, this can be done with the following approaches:
// Create a new table with columns and unnamed constraints create.createTable("table") .column("column1", INTEGER) .column("column2", INTEGER) .column("column3", INTEGER) .unique("column1") .unique("column2", "column3") .execute(); // Equivalent to the above create.createTable("table") .column("column1", INTEGER) .column("column2", INTEGER) .column("column3", INTEGER) .constraints( unique("column1"), unique("column2", "column3") ) .execute(); // Create a new table with columns and named constraints (recommended if you want to alter the constraint) create.createTable("table") .column("column1", INTEGER) .column("column2", INTEGER) .column("column3", INTEGER) .constraints( constraint("uk1").unique("column1"), constraint("uk2").unique("column2", "column3") ) .execute();
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER) .constraints( constraint("uk").unique("column1") )
Translates to the following dialect specific expressions:
-- ACCESS, DB2, FIREBIRD, HANA, TERADATA CREATE TABLE table ( column1 integer, CONSTRAINT uk UNIQUE (column1) ) -- ASE, SYBASE CREATE TABLE table ( column1 int NULL, CONSTRAINT uk UNIQUE (column1) ) -- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, -- SQLSERVER, VERTICA, YUGABYTEDB CREATE TABLE table ( column1 int, CONSTRAINT uk UNIQUE (column1) ) -- BIGQUERY CREATE TABLE table ( column1 int64 ) -- COCKROACHDB CREATE TABLE table ( column1 int4, CONSTRAINT uk UNIQUE (column1) ) -- INFORMIX CREATE TABLE table ( column1 integer, UNIQUE (column1) CONSTRAINT uk ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( column1 number(10), CONSTRAINT uk UNIQUE (column1) ) -- SQLDATAWAREHOUSE CREATE TABLE table ( column1 int, CONSTRAINT uk UNIQUE (column1) NOT ENFORCED ) -- SQLITE CREATE TABLE "table" ( column1 int, CONSTRAINT uk UNIQUE (column1) ) -- TRINO CREATE TABLE table ( column1 int )
4.6.3.8.8. Foreign keys
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A foreign key is a tool that helps further normalise your database by guaranteeing that a referenced value exists in a parent table. In our sample database, it enforces the integrity of the BOOK.AUTHOR_ID
reference. Besides integrity, it can be a very useful tool for optimising more sophisticated execution plans, e.g. to support JOIN elimination. In jOOQ, create foreign keys like this:
// Create a new table with columns and unnamed constraints create.createTable("table") .column("column1", INTEGER) .constraints( foreignKey("column1").references("other_table", "other_column1") ) .execute(); // Create a new table with columns and named constraints (recommended if you want to alter the constraint) create.createTable("table") .column("column1", INTEGER) .constraints( constraint("fk").foreignKey("column1").references("other_table", "other_column1") ) .execute();
jOOQ's code generator will pick up foreign keys for a variety of purposes, including navigational methods, the ON KEY joins and most prominently, the very powerful implicit joins.
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER) .constraints( constraint("fk").foreignKey("column1").references("other_table", "other_column1") )
Translates to the following dialect specific expressions:
-- ACCESS, DB2, FIREBIRD, HANA, TERADATA CREATE TABLE table ( column1 integer, CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- ASE, SYBASE CREATE TABLE table ( column1 int NULL, CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- AURORA_MYSQL, AURORA_POSTGRES, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, -- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB CREATE TABLE table ( column1 int, CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- BIGQUERY CREATE TABLE table ( column1 int64 ) -- COCKROACHDB CREATE TABLE table ( column1 int4, CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- INFORMIX CREATE TABLE table ( column1 integer, FOREIGN KEY (column1) REFERENCES other_table (other_column1) CONSTRAINT fk ) -- ORACLE, SNOWFLAKE CREATE TABLE table ( column1 number(10), CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- SQLITE CREATE TABLE "table" ( column1 int, CONSTRAINT fk FOREIGN KEY (column1) REFERENCES other_table (other_column1) ) -- TRINO CREATE TABLE table ( column1 int )
4.6.3.8.9. Check constraints
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A CHECK
constraint is a simple, yet very effective means of enforcing data integrity on a row basis. Want to ensure a number is only ever positive? Use a CHECK
constraint (or even a DOMAIN that contains a CHECK
constraint).
// Create a new table with columns and unnamed constraints create.createTable("table") .column("column1", INTEGER) .check(field(name("column1"), INTEGER).gt(0)) .execute(); // Equivalent to the above create.createTable("table") .column("column1", INTEGER) .constraints( check(field(name("column1"), INTEGER).gt(0)) ) .execute(); // Create a new table with columns and named constraints (recommended if you want to alter the constraint) create.createTable("table") .column("column1", INTEGER) .constraints( constraint("chk").check(field(name("column1"), INTEGER).gt(0)) ) .execute();
Just like the previous constraints, this one can be used by the optimiser to remove some redundant predicates, see e.g. this blog post.
Dialect support
This example using jOOQ:
createTable("table") .column("column1", INTEGER) .constraints( constraint("chk").check(field(name("column1"), INTEGER).gt(0)) )
Translates to the following dialect specific expressions:
-- ACCESS, DB2, FIREBIRD, HANA, TERADATA CREATE TABLE table ( column1 integer, CONSTRAINT chk CHECK (column1 > 0) ) -- ASE, SYBASE CREATE TABLE table ( column1 int NULL, CONSTRAINT chk CHECK (column1 > 0) ) -- AURORA_POSTGRES, DERBY, H2, HSQLDB, MARIADB, MYSQL, POSTGRES, SQLSERVER, VERTICA, YUGABYTEDB CREATE TABLE table ( column1 int, CONSTRAINT chk CHECK (column1 > 0) ) -- COCKROACHDB CREATE TABLE table ( column1 int4, CONSTRAINT chk CHECK (column1 > 0) ) -- INFORMIX CREATE TABLE table ( column1 integer, CHECK (column1 > 0) CONSTRAINT chk ) -- ORACLE CREATE TABLE table ( column1 number(10), CONSTRAINT chk CHECK (column1 > 0) ) -- SQLITE CREATE TABLE "table" ( column1 int, CONSTRAINT chk CHECK (column1 > 0) ) -- AURORA_MYSQL, BIGQUERY, DUCKDB, EXASOL, MEMSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, TRINO /* UNSUPPORTED */
4.6.3.8.10. From a SELECT
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Occasionally, creating a table from a SELECT statement is very useful, copying the source table's data types and data.
// Create a new table from a source SELECT statement create.createTable("book_archive") .as(select(BOOK.ID, BOOK.TITLE).from(BOOK)) .execute(); // Create a new table from a source SELECT statement and specify that data should be included, explicitly create.createTable("book_archive") .as(select(BOOK.ID, BOOK.TITLE).from(BOOK)) .withData() .execute(); // Create a new table from a source SELECT statement and specify that data should be excluded, explicitly create.createTable("book_archive") .as(select(BOOK.ID, BOOK.TITLE).from(BOOK)) .withNoData() .execute();
Dialect support
This example using jOOQ:
createTable("book_archive") .as(select(BOOK.ID, BOOK.TITLE).from(BOOK)) .withNoData()
Translates to the following dialect specific expressions:
-- ACCESS, ASE, SQLDATAWAREHOUSE, SQLSERVER SELECT BOOK.ID, BOOK.TITLE INTO book_archive FROM BOOK WHERE 1 = 0 -- AURORA_MYSQL, MEMSQL, ORACLE, REDSHIFT, SQLITE, VERTICA CREATE TABLE book_archive AS SELECT BOOK.ID, BOOK.TITLE FROM BOOK WHERE 1 = 0 -- AURORA_POSTGRES, DERBY, EXASOL, POSTGRES, YUGABYTEDB CREATE TABLE book_archive AS SELECT BOOK.ID, BOOK.TITLE FROM BOOK WITH NO DATA -- COCKROACHDB, DUCKDB, H2, MARIADB, MYSQL, SNOWFLAKE CREATE TABLE book_archive AS SELECT BOOK.ID, BOOK.TITLE FROM BOOK WHERE FALSE -- DB2 CREATE TABLE book_archive AS ( SELECT BOOK.ID, BOOK.TITLE FROM BOOK ) WITH NO DATA -- HANA, HSQLDB CREATE TABLE book_archive AS ( SELECT BOOK.ID, BOOK.TITLE FROM BOOK ) WITH NO DATA -- TERADATA CREATE TABLE book_archive AS ( SELECT BOOK.ID, BOOK.TITLE FROM BOOK WHERE 1 = 0 ) WITH DATA -- BIGQUERY, FIREBIRD, INFORMIX, SYBASE, TRINO /* UNSUPPORTED */
4.6.3.8.11. Temporary tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Many dialects support different notions of "temporary" tables, i.e. tables whose data and/or meta data is stored only temporarily. The details of these temporary are implementation specific. jOOQ supports the following syntaxes, both with explicit column lists or as CREATE TABLE AS SELECT:
// Create a new temporary table create.createTemporaryTable("book_archive") .column("column1", INTEGER) .execute(); // Create a new temporary table create.createGlobalTemporaryTable("book_archive") .column("column1", INTEGER) .execute();
Dialect support
This example using jOOQ:
createTemporaryTable("book_archive") .column("column1", INTEGER)
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, AURORA_POSTGRES, DUCKDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, YUGABYTEDB CREATE TEMPORARY TABLE book_archive ( column1 int ) -- COCKROACHDB CREATE GLOBAL TEMPORARY TABLE book_archive ( column1 int4 ) -- FIREBIRD, HANA, TERADATA CREATE GLOBAL TEMPORARY TABLE book_archive ( column1 integer ) -- ORACLE, SNOWFLAKE CREATE GLOBAL TEMPORARY TABLE book_archive ( column1 number(10) ) -- VERTICA CREATE GLOBAL TEMPORARY TABLE book_archive ( column1 int ) -- ACCESS, ASE, BIGQUERY, DB2, DERBY, EXASOL, H2, HSQLDB, INFORMIX, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TRINO /* UNSUPPORTED */
4.6.3.9. CREATE TRIGGER
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most dialects support triggers, which is SQL or procedural logic that executes at certain events to perform actions including:
- Changing the data about to be inserted or updated (e.g. when a column
DEFAULT
in a table definition doesn't do the trick) - Performing additional integrity checks prior to any DML statement (e.g. when a
CHECK
constraint doesn't suffice) - Logging extra data, such as audit data.
- Etc.
4.6.3.9.1. Events
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most dialects supporting triggers can fire ...
-
BEFORE
-
AFTER
-
INSTEAD OF
... a certain event, including ...
-
INSERT
-
UPDATE
-
DELETE
Note that the above refer to events, not the statements, meaning that a trigger may fire also for the MERGE statement.
Some examples illustrating possible triggers:
create.createTrigger("trg1") .beforeInsert() .on(BOOK) .forEachRow() .as(insertInto(LOG).columns(LOG.TEXT).values("Row inserted in BOOK")) .execute(); create.createTrigger("trg") .beforeUpdate() .on(BOOK) .forEachRow() .as(insertInto(LOG).columns(LOG.TEXT).values("Row updated in BOOK")) .execute(); create.createTrigger("trg") .beforeDelete() .on(BOOK) .forEachRow() .as(insertInto(LOG).columns(LOG.TEXT).values("Row deleted in BOOK")) .execute(); create.createTrigger("trg") .beforeInsert().orUpdate().orDelete() .on(BOOK) .forEachRow() .as(insertInto(LOG).columns(LOG.TEXT).values("Row inserted or updated or deleted in BOOK")) .execute();
4.6.3.9.2. REFERENCING clause
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A trigger is executed while a data mutation is being executed. During this time, it is possible for a trigger to see a row or table's state before (OLD
pseudo table) or after (NEW
pseudo table) the modification. Specifically:
-
INSERT
: OnlyNEW
is available -
UPDATE
: BothOLD
andNEW
are available -
DELETE
: OnlyOLD
is available
In the rare event when the default OLD
or NEW
pseudo table identifiers conflict with actual tables in the schema, the REFERENCING
clause can be used to rename these identifiers for the scope of a trigger. In some dialects, REFERENCING
is always mandatory, and in others, it's not supported at all.
An example would be
// A trigger that prevents the update of NULL titles in BOOK create.createTrigger("trg") .beforeUpdate().of(BOOK.TITLE) .on(BOOK) .referencingOldAs("o") .referencingNewAs("n") .forEachRow() .as(if_(BOOK.as("o").TITLE.isNull()).then( variable(BOOK.as("n").TITLE.getQualifiedName(), BOOK.TITLE.getDataType()).setNull() )) .execute();
4.6.3.9.3. STATEMENT vs ROW triggers
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A trigger can choose whether it fires only once for entire sets of data being changed (FOR EACH STATEMENT
), or for each individual row (FOR EACH ROW
). The specific semantics of each of these clauses, and what's possible to do with each is vendor specific. Please refer to your database manual to see what's possible here.
An example of such triggers:
create.createTrigger("trg") .beforeInsert() .on(BOOK) .forEachRow() .as(insertInto(LOG).columns(LOG.TEXT).values("Row inserted in BOOK")) .execute(); create.createTrigger("trg") .beforeInsert() .on(BOOK) .forEachStatement() .as(insertInto(LOG).columns(LOG.TEXT).values("Rows inserted in BOOK")) .execute();
4.6.3.9.4. WHEN clause
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A trigger can specify a filter, which helps avoid context switching, etc. when the trigger does not need to be fired. This can be achieved with the WHEN
clause, which can access the OLD
and NEW
pseudo table columns, see also the REFERENCING clause.
create.createTrigger("trg") .beforeInsert() .on(BOOK) .referencingNewAs("n") .forEachRow() .when(BOOK.as("n").TITLE.isNotNull()) .as(insertInto(LOG).columns(LOG.TEXT).values("Row inserted in BOOK")) .execute();
4.6.3.10. CREATE TYPE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The only type currently supported by jOOQ is the PostgreSQL ENUM
type:
// Create a new ENUM type create.createType("weekday") .asEnum("mon", "tue", "wed", "thu", "fri", "sat", "sun") .execute();
Dialect support
This example using jOOQ:
createType("t").asEnum("a", "b", "c")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, POSTGRES, YUGABYTEDB CREATE TYPE t AS ENUM ('a', 'b', 'c') -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.3.11. CREATE VIEW
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement allows for creating a VIEW
in the database catalog:
// Create a new view create.createView("books_and_authors", "author_id", "first_name", "last_name", "book_id", "title") .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.ID, BOOK.TITLE) .from(AUTHOR) .join(BOOK).on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))) .execute();
Dialect support
This example using jOOQ:
createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR))
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, -- HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, -- TERADATA, VERTICA, YUGABYTEDB CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR -- MEMSQL CREATE VIEW a AS SELECT t.id FROM ( SELECT AUTHOR.ID id FROM AUTHOR ) t -- TRINO CREATE VIEW a AS SELECT t.id FROM ( SELECT AUTHOR.ID FROM AUTHOR ) t (id)
4.6.3.11.1. OR REPLACE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Many dialects support a convenient OR REPLACE
clause that allows for dropping any pre-existing view by the same name in a single statement.
// Create a new view create.createOrReplaceView("early_authors", "author_id", "first_name", "last_name") .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(AUTHOR) // Any inserted or updated authors must continue to satisfy this condition .where(AUTHOR.ID.lt(200))) .execute();
Dialect support
This example using jOOQ:
createOrReplaceView("a", "id").as(select(AUTHOR.ID).from(AUTHOR))
Translates to the following dialect specific expressions:
-- ASE, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DUCKDB, EXASOL, H2, HANA, MARIADB, MYSQL, ORACLE, POSTGRES, VERTICA, -- YUGABYTEDB CREATE OR REPLACE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR -- FIREBIRD, SQLSERVER CREATE OR ALTER VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR -- TERADATA REPLACE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR -- TRINO CREATE OR REPLACE VIEW a AS SELECT t.id FROM ( SELECT AUTHOR.ID FROM AUTHOR ) t (id) -- ACCESS, AURORA_MYSQL, DERBY, HSQLDB, INFORMIX, MEMSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE /* UNSUPPORTED */
4.6.3.11.2. WITH CHECK OPTION
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A CREATE VIEW statement of an updatable view can have a WITH CHECK OPTION
clause appended to it, to make sure that any INSERT or UPDATE statement will produce rows that are also visible through this view.
// Create a new view create.createView("early_authors", "author_id", "first_name", "last_name") .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(AUTHOR) // Any inserted or updated authors must continue to satisfy this condition .where(AUTHOR.ID.lt(200)) // The flag is set on the Select object, not the view .withCheckOption()) .execute();
The flag is set on theSELECT
object, not theCREATE VIEW
statement, as it is also made available to inline views.
Dialect support
This example using jOOQ:
createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR).withCheckOption())
Translates to the following dialect specific expressions:
-- ASE, DB2, FIREBIRD, HANA, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLSERVER, SYBASE, TERADATA CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR WITH CHECK OPTION -- ACCESS, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HSQLDB, MEMSQL, REDSHIFT, -- SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.3.11.3. WITH READ ONLY
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A CREATE VIEW statement of an updatable view can have a WITH READ ONLY
clause appended to it, to make sure that it cannot be updated.
// Create a new view create.createView("authors", "author_id", "first_name", "last_name") .as(select(AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(AUTHOR) .withReadOnly()) .execute();
The flag is set on theSELECT
object, not theCREATE VIEW
statement, as it is also made available to inline views.
Dialect support
This example using jOOQ:
createView("a", "id").as(select(AUTHOR.ID).from(AUTHOR).withReadOnly())
Translates to the following dialect specific expressions:
-- ACCESS CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM ( SELECT count(*) dual FROM MSysResources ) AS dual WHERE 1 = 0 -- ASE, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, VERTICA CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL WHERE 1 = 0 -- AURORA_MYSQL CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM DUAL WHERE 1 = 0 -- AURORA_POSTGRES, COCKROACHDB, H2, MARIADB, MYSQL, POSTGRES, SNOWFLAKE, YUGABYTEDB CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL WHERE FALSE -- BIGQUERY CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION DISTINCT SELECT NULL FROM UNNEST([STRUCT(1 AS dual)]) AS dual WHERE FALSE -- DB2 CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM SYSIBM.DUAL WHERE 1 = 0 -- DERBY CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT CAST(NULL AS int) FROM SYSIBM.SYSDUMMY1 WHERE FALSE -- EXASOL CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM DUAL WHERE FALSE -- FIREBIRD CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM RDB$DATABASE WHERE 1 = 0 -- HANA, ORACLE CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR WITH READ ONLY -- HSQLDB CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM (VALUES(1)) AS dual(dual) WHERE FALSE -- INFORMIX CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM ( SELECT 1 AS dual FROM systables WHERE (tabid = 1) ) AS dual WHERE 1 = 0 -- MEMSQL CREATE VIEW a AS SELECT t.id FROM ( SELECT t.* FROM ( SELECT AUTHOR.ID id FROM AUTHOR UNION SELECT NULL FROM DUAL WHERE 1 = 0 ) t ) t -- SYBASE CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM SYS.DUMMY WHERE 1 = 0 -- TERADATA CREATE VIEW a(id) AS SELECT AUTHOR.ID FROM AUTHOR UNION SELECT NULL FROM ( SELECT 1 AS "dual" ) AS "dual" WHERE 1 = 0 -- DUCKDB, TRINO /* UNSUPPORTED */
4.6.4. The DROP statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DROP
statement is used to drop objects from the database catalog.
4.6.4.1. DROP DATABASE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop a DATABASE
.
// Drop a database create.dropDatabase("database").execute();
Dialect support
This example using jOOQ:
dropDatabase("t")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, MARIADB, MEMSQL, MYSQL, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, YUGABYTEDB DROP DATABASE t -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, ORACLE, -- REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.1.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a database create.dropDatabaseIfExists("database").execute();
Dialect support
This example using jOOQ:
dropDatabaseIfExists("database")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, MARIADB, MEMSQL, MYSQL, POSTGRES, YUGABYTEDB DROP DATABASE IF EXISTS database -- SQLDATAWAREHOUSE BEGIN TRY DROP DATABASE database END TRY BEGIN CATCH IF error_number() != 2714 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLSERVER BEGIN TRY DROP DATABASE database END TRY BEGIN CATCH IF error_number() != 2714 THROW; END CATCH -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, ORACLE, -- REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.2. DROP DOMAIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The DROP DOMAIN
statement allows for droping DOMAIN types.
create.dropDomain("d").execute();
CASCADE
It is possible to supply a CASCADE
or RESTRICT
clause, explicitly
// Specify the CASCADE / RESTRICT clauses explicitly create.dropDomain("d").cascade().execute(); create.dropDomain("d").restrict().execute();
Please refer to your database manual for an understanding of the semantics of CASCADE
(e.g. in PostgreSQL, all referencing columns are dropped!)
Dialect support
This example using jOOQ:
dropDomain("d")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, FIREBIRD, H2, HSQLDB, ORACLE, POSTGRES, YUGABYTEDB DROP DOMAIN d -- SQLSERVER DROP TYPE d -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, -- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.2.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a domain create.dropDomainIfExists("d").execute();
Dialect support
This example using jOOQ:
dropDomainIfExists("d")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, H2, HSQLDB, ORACLE, POSTGRES, YUGABYTEDB DROP DOMAIN IF EXISTS d -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP DOMAIN d '; WHEN sqlcode -607 DO BEGIN END END -- SQLSERVER DROP TYPE IF EXISTS d -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, HANA, INFORMIX, MARIADB, MEMSQL, MYSQL, -- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.3. DROP FUNCTION
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop a FUNCTION
from the database catalog.
// Drop a function create.dropFunction("func").execute();
Dialect support
This example using jOOQ:
dropFunction("f")
Translates to the following dialect specific expressions:
-- BIGQUERY, DB2, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, -- VERTICA, YUGABYTEDB DROP FUNCTION f -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, H2, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, -- SYBASE, TERADATA, TRINO /* UNSUPPORTED */
4.6.4.3.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a function create.dropFunctionIfExists("func").execute();
Dialect support
This example using jOOQ:
dropFunctionIfExists("func")
Translates to the following dialect specific expressions:
-- BIGQUERY, EXASOL, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLSERVER, VERTICA, YUGABYTEDB DROP FUNCTION IF EXISTS func -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP FUNCTION func '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP FUNCTION func '; WHEN sqlcode -607 DO BEGIN END END -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, H2, HANA, MEMSQL, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO /* UNSUPPORTED */
4.6.4.4. DROP INDEX
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an INDEX
from the database catalog.
// Drop an index (for indexes stored in the schema namespace, i.e. most dialects) create.dropIndex("index").execute(); // Drop an index (for indexes stored in the table namespace, e.g. MySQL, SQL Server) create.dropIndex("index").on("table").execute();
CASCADE
It is possible to supply a CASCADE
or RESTRICT
clause, explicitly
// Specify the CASCADE / RESTRICT clauses explicitly create.dropIndex("index").cascade().execute(); create.dropIndex("index").restrict().execute();
Dialect support
This example using jOOQ:
dropIndex("i")
Translates to the following dialect specific expressions:
-- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, -- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, YUGABYTEDB DROP INDEX i -- BIGQUERY, EXASOL, REDSHIFT, SNOWFLAKE, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.4.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop an index create.dropIndexIfExists("index").execute();
Dialect support
This example using jOOQ:
dropIndexIfExists("index")
Translates to the following dialect specific expressions:
-- ACCESS DROP INDEX index -- AURORA_POSTGRES, COCKROACHDB, DUCKDB, H2, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SYBASE, YUGABYTEDB DROP INDEX IF EXISTS index -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP INDEX index '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP INDEX index '; WHEN sqlcode -607 DO BEGIN END END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 261 BEGIN END; EXECUTE IMMEDIATE ' DROP INDEX index '; END; -- MYSQL CREATE PROCEDURE block_1700915565467_8559950() MODIFIES SQL DATA BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42000' BEGIN END; DROP INDEX index; END; CALL block_1700915565467_8559950(); DROP PROCEDURE block_1700915565467_8559950; -- SQLDATAWAREHOUSE BEGIN TRY DROP INDEX index END TRY BEGIN CATCH IF error_number() != 3701 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLITE DROP INDEX IF EXISTS "index" -- SQLSERVER BEGIN TRY DROP INDEX index END TRY BEGIN CATCH IF error_number() != 3701 THROW; END CATCH -- ASE, AURORA_MYSQL, BIGQUERY, DERBY, EXASOL, MEMSQL, REDSHIFT, SNOWFLAKE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.5. DROP PROCEDURE
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop a PROCEDURE
from the database catalog.
// Drop a procedure create.dropProcedure("proc").execute();
Dialect support
This example using jOOQ:
dropProcedure("p")
Translates to the following dialect specific expressions:
-- BIGQUERY, DB2, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLDATAWAREHOUSE, SQLSERVER, -- YUGABYTEDB DROP PROCEDURE p -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, MEMSQL, REDSHIFT, SNOWFLAKE, -- SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.5.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a procedure create.dropProcedureIfExists("procedure").execute();
Dialect support
This example using jOOQ:
dropProcedureIfExists("procedure")
Translates to the following dialect specific expressions:
-- BIGQUERY, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, SQLSERVER, YUGABYTEDB DROP PROCEDURE IF EXISTS procedure -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP PROCEDURE procedure '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP PROCEDURE procedure '; WHEN sqlcode -607 DO BEGIN END END -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HANA, MEMSQL, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.6. DROP SCHEMA
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an SCHEMA
from the database catalog.
// Drop a schema create.dropSchema("schema").execute();
CASCADE
It is possible to supply a CASCADE
or RESTRICT
clause, explicitly
// Specify the CASCADE / RESTRICT clauses explicitly create.dropSchema("schema").cascade().execute(); create.dropSchema("schema").restrict().execute();
Dialect support
This example using jOOQ:
dropSchema("s")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HANA, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLSERVER, VERTICA, YUGABYTEDB DROP SCHEMA s -- DB2, DERBY DROP SCHEMA s RESTRICT -- ORACLE DROP USER s -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO /* UNSUPPORTED */
4.6.4.6.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a schema create.dropSchemaIfExists("schema").execute();
Dialect support
This example using jOOQ:
dropSchemaIfExists("schema")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, -- VERTICA, YUGABYTEDB DROP SCHEMA IF EXISTS schema -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP SCHEMA schema RESTRICT '; END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 362 BEGIN END; EXECUTE IMMEDIATE ' DROP SCHEMA schema '; END; -- ORACLE DROP USER IF EXISTS schema -- SQLDATAWAREHOUSE BEGIN TRY DROP SCHEMA schema END TRY BEGIN CATCH IF error_number() != 15151 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLSERVER BEGIN TRY DROP SCHEMA schema END TRY BEGIN CATCH IF error_number() != 15151 THROW; END CATCH -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, FIREBIRD, INFORMIX, SQLITE, SYBASE, TERADATA, TRINO /* UNSUPPORTED */
4.6.4.7. DROP SEQUENCE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an SEQUENCE
from the database catalog.
// Drop a sequence create.dropSequence("sequence").execute();
Dialect support
This example using jOOQ:
dropSequence("s")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SNOWFLAKE, -- SQLSERVER, SYBASE, VERTICA, YUGABYTEDB DROP SEQUENCE s -- DERBY DROP SEQUENCE s RESTRICT -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DUCKDB, EXASOL, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, TERADATA, -- TRINO /* UNSUPPORTED */
4.6.4.7.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a sequence create.dropSequenceIfExists("sequence").execute();
Dialect support
This example using jOOQ:
dropSequenceIfExists("sequence")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, HSQLDB, INFORMIX, MARIADB, ORACLE, POSTGRES, SNOWFLAKE, VERTICA, YUGABYTEDB DROP SEQUENCE IF EXISTS sequence -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP SEQUENCE sequence '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP SEQUENCE sequence '; WHEN sqlcode -607 DO BEGIN END END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 313 BEGIN END; EXECUTE IMMEDIATE ' DROP SEQUENCE sequence '; END; -- SQLSERVER BEGIN TRY DROP SEQUENCE sequence END TRY BEGIN CATCH IF error_number() != 3701 THROW; END CATCH -- SYBASE BEGIN DROP SEQUENCE sequence; EXCEPTION WHEN others THEN END;BEGIN DROP SEQUENCE sequence '; WHEN sqlcode -607 DO BEGIN END END; -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, MEMSQL, MYSQL, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, -- TERADATA, TRINO /* UNSUPPORTED */
4.6.4.8. DROP TABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an TABLE
from the database catalog.
// Drop a table create.dropTable("table").execute();
CASCADE
It is possible to supply a CASCADE
or RESTRICT
clause, explicitly
// Specify the CASCADE / RESTRICT clauses explicitly create.dropTable("table").cascade().execute(); create.dropTable("table").restrict().execute();
Dialect support
This example using jOOQ:
dropTable("t")
Translates to the following dialect specific expressions:
-- All dialects DROP TABLE t
4.6.4.8.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a table create.dropTableIfExists("table").execute();
Dialect support
This example using jOOQ:
dropTableIfExists("table")
Translates to the following dialect specific expressions:
-- ACCESS DROP TABLE table -- AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, -- POSTGRES, SNOWFLAKE, SYBASE, VERTICA, YUGABYTEDB DROP TABLE IF EXISTS table -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP TABLE table '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP TABLE table '; WHEN sqlcode -607 DO BEGIN END END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 259 BEGIN END; EXECUTE IMMEDIATE ' DROP TABLE table '; END; -- SQLDATAWAREHOUSE BEGIN TRY DROP TABLE table END TRY BEGIN CATCH IF error_number() != 3701 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLITE DROP TABLE IF EXISTS "table" -- SQLSERVER BEGIN TRY DROP TABLE table END TRY BEGIN CATCH IF error_number() != 3701 THROW; END CATCH -- ASE, BIGQUERY, DERBY, REDSHIFT, TERADATA, TRINO /* UNSUPPORTED */
4.6.4.9. DROP TRIGGER
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop a TRIGGER
from the database catalog.
// Drop a trigger create.dropTrigger("trg").execute();
Dialect support
This example using jOOQ:
dropTrigger("t")
Translates to the following dialect specific expressions:
-- DB2, DERBY, FIREBIRD, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, SQLITE, SQLSERVER, YUGABYTEDB DROP TRIGGER t -- POSTGRES DO $$ BEGIN DROP TRIGGER t; DROP FUNCTION t_function; END; $$ -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, HANA, MEMSQL, REDSHIFT, -- SNOWFLAKE, SQLDATAWAREHOUSE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.9.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a trigger create.dropTriggerIfExists("trg").execute();
Dialect support
This example using jOOQ:
dropTriggerIfExists("type")
Translates to the following dialect specific expressions:
-- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP TRIGGER type '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP TRIGGER type '; WHEN sqlcode -607 DO BEGIN END END -- INFORMIX, MARIADB, MYSQL, ORACLE, SQLSERVER DROP TRIGGER IF EXISTS type -- POSTGRES DO $$ BEGIN DROP TRIGGER IF EXISTS type; DROP FUNCTION IF EXISTS type_function; END; $$ -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, MEMSQL, -- REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.4.10. DROP TYPE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an TYPE
from the database catalog.
// Drop a type create.dropType("type").execute();
CASCADE
It is possible to supply a CASCADE
or RESTRICT
clause, explicitly
// Specify the CASCADE / RESTRICT clauses explicitly create.dropType("type").cascade().execute(); create.dropType("type").restrict().execute();
Dialect support
This example using jOOQ:
dropType("t")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, ORACLE, POSTGRES, YUGABYTEDB DROP TYPE t -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.10.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a type create.dropTypeIfExists("type").execute();
Dialect support
This example using jOOQ:
dropTypeIfExists("type")
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, H2, ORACLE, POSTGRES, YUGABYTEDB DROP TYPE IF EXISTS type -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, -- MYSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.6.4.11. DROP VIEW
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
This statement is used to drop an VIEW
from the database catalog.
// Drop a view create.dropView("view").execute();
Dialect support
This example using jOOQ:
dropView("v")
Translates to the following dialect specific expressions:
-- All dialects DROP VIEW v
4.6.4.11.1. IF EXISTS
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
For idempotent execution of DDL scripts, the useful IF EXISTS
clause is supported by jOOQ, and emulated using an anonymous, procedural block if possible.
// Drop a view create.dropViewIfExists("view").execute();
Dialect support
This example using jOOQ:
dropViewIfExists("v")
Translates to the following dialect specific expressions:
-- ACCESS DROP VIEW v -- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, -- ORACLE, POSTGRES, SQLITE, SYBASE, TRINO, VERTICA, YUGABYTEDB DROP VIEW IF EXISTS v -- DB2 BEGIN DECLARE CONTINUE HANDLER FOR SQLSTATE '42704' BEGIN END; EXECUTE IMMEDIATE ' DROP VIEW v '; END -- FIREBIRD EXECUTE BLOCK AS BEGIN EXECUTE STATEMENT ' DROP VIEW v '; WHEN sqlcode -607 DO BEGIN END END -- HANA DO BEGIN DECLARE EXIT HANDLER FOR SQL_ERROR_CODE 321 BEGIN END; EXECUTE IMMEDIATE ' DROP VIEW v '; END; -- SQLDATAWAREHOUSE BEGIN TRY DROP VIEW v END TRY BEGIN CATCH IF error_number() != 3701 BEGIN DECLARE @ErrorMessage NVARCHAR(4000) = ERROR_MESSAGE(); DECLARE @ErrorSeverity INT = ERROR_SEVERITY(); DECLARE @ErrorState INT = ERROR_STATE(); RAISERROR (@ErrorMessage, @ErrorSeverity, @ErrorState); END; END CATCH -- SQLSERVER BEGIN TRY DROP VIEW v END TRY BEGIN CATCH IF error_number() != 3701 THROW; END CATCH -- ASE, DERBY, REDSHIFT, SNOWFLAKE, TERADATA /* UNSUPPORTED */
4.6.5. The GRANT statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Databases that implement access control for their database catalog allow for using GRANT
and REVOKE privileges from org.jooq.User
and org.jooq.Role
objects. In jOOQ, this can be done as follows:
// Define privileges Privilege select = privilege("select"); Privilege insert = privilege("insert"); User user = user("user"); // Grant privileges to a given user or role create.grant(select, insert).on(BOOK).to(user).execute(); // Grant privileges to a given user or role with the grant option create.grant(select, insert).on(BOOK).to(user).withGrantOption().execute(); // Grant privileges to everyone create.grant(select, insert).on(BOOK).toPublic().execute();
4.6.6. The REVOKE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Databases that implement access control for their database catalog allow for using GRANT and REVOKE
privileges from org.jooq.User
and org.jooq.Role
objects. In jOOQ, this can be done as follows:
// Define privileges Privilege select = privilege("select"); Privilege insert = privilege("insert"); User user = user("user"); // Revoke privileges from a given user or role create.revoke(select, insert).on(BOOK).from(user).execute(); // Revoke the grant option from a given user or role create.revokeGrantOptionFor(select, insert).on(BOOK).from(user).execute(); // Revoke privileges from everyone create.revoke(select, insert).on(BOOK).fromPublic().execute();
4.6.7. The SET statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most databases support a variety of SET
statements to set session specific environment variables.
4.6.7.1. SET CATALOG
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Depending on whether your database product supports catalogs and schemas, the below SET
statement may be supported to set the current session's catalog (e.g. the database).
SET CATALOG catalogname;
create.setCatalog("catalogname").execute();
Dialect support
This example using jOOQ:
setCatalog("c")
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SQLSERVER USE c -- DUCKDB SET CATALOG c -- SNOWFLAKE USE DATABASE c -- TERADATA DATABASE c -- ACCESS, ASE, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, ORACLE, -- POSTGRES, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SYBASE, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.6.7.2. SET SCHEMA
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Depending on whether your database product supports catalogs and schemas, the below SET
statement may be supported to set the current session's schema.
SET SCHEMA schemaname;
create.setSchema("schemaname").execute();
Dialect support
This example using jOOQ:
setSchema("c")
Translates to the following dialect specific expressions:
-- AURORA_MYSQL, MARIADB, MEMSQL, MYSQL, SNOWFLAKE USE c -- AURORA_POSTGRES, COCKROACHDB, POSTGRES, VERTICA, YUGABYTEDB SET SEARCH_PATH = c -- DB2, DERBY, DUCKDB, H2, HSQLDB SET SCHEMA c -- EXASOL OPEN SCHEMA c -- ORACLE ALTER SESSION SET CURRENT_SCHEMA = c -- TERADATA DATABASE c -- ACCESS, ASE, BIGQUERY, FIREBIRD, HANA, INFORMIX, REDSHIFT, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TRINO /* UNSUPPORTED */
4.6.8. The TRUNCATE statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Even if the TRUNCATE
statement mainly modifies data, it is generally considered to be a DDL statement. It is popular in many databases when you want to bypass constraints for table truncation. Databases may behave differently, when a truncated table is referenced by other tables. For instance, they may fail if records from a truncated table are referenced, even with ON DELETE CASCADE
clauses in place. Please, consider your database manual to learn more about its TRUNCATE
implementation.
The TRUNCATE
syntax is trivial:
create.truncate(AUTHOR).execute();
TRUNCATE
is not supported by all dialects. jOOQ will execute a DELETE FROM AUTHOR
statement instead, which is roughly equivalent.
Dialect support
This example using jOOQ:
truncate(AUTHOR)
Translates to the following dialect specific expressions:
-- ACCESS, FIREBIRD, SQLITE, TERADATA DELETE FROM AUTHOR -- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, -- MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE, TRINO, VERTICA, YUGABYTEDB TRUNCATE TABLE AUTHOR -- DB2 TRUNCATE TABLE AUTHOR IMMEDIATE
4.6.9. Generating DDL from objects
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When using jOOQ's code generator, a whole set of meta data is generated with the generated artefacts, such as schemas, tables, columns, data types, constraints, default values, etc.
This meta data can be used to generate DDL CREATE
statements in any SQL dialect, in order to partially restore the original schema again on a new database instance. This is particularly useful, for instance, when working with an Oracle production database, and an H2 in-memory test database. The following code produces the DDL for a schema:
// SCHEMA is the generated schema that contains a reference to all generated tables Queries ddl = DSL.using(configuration) .ddl(SCHEMA); for (Query query : ddl.queries()) { System.out.println(query); }
When executing the above, you should see something like the following:
create table "PUBLIC"."AUTHOR"( "ID" int not null, "FIRST_NAME" varchar(50) null, "LAST_NAME" varchar(50) not null, ... constraint "PK_AUTHOR" primary key ("ID") ) create table "PUBLIC"."BOOK"( "ID" int not null, "AUTHOR_ID" int not null, "TITLE" varchar(400) not null, ... constraint "PK_BOOK" primary key ("ID") ) ... alter table "PUBLIC"."BOOK" add constraint "FK_BOOK_AUTHOR_ID" foreign key ("AUTHOR_ID") references "AUTHOR" ("ID")
Do note that these features only restore parts of the original schema. For instance, vendor-specific storage clauses that are not available to jOOQ's generated meta data cannot be reproduced this way.
4.7. Procedural statements
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most RDBMS support some sort of procedural language that allows for running imperative code inside of the database. The syntax of these languages is often similar, and hence it is supported and standardised by jOOQ as well.
In some databases, the procedural language can exist in the form of anonymous blocks, i.e. ad-hoc programs that are interpreted (or compiled) on the fly. In most RDBMS, however, the main approach to using the procedural languages is to store the procedural logic in stored procedures or functions, such that they can be pre-compiled and translated to native code for performance reasons.
The jOOQ API currently supports anonymous blocks only. In some dialects where anonymous blocks are not supported, a procedure is stored, called, and dropped again as an emulation.
An example of an anonymous block that inserts values 1 - 10 into a table:
-- PL/SQL syntax BEGIN FOR i IN 1 .. 10 LOOP INSERT INTO t (col) VALUES (i); END LOOP; END;
Variable<Integer> i = var(name("i"), INTEGER); create.begin( for_(i).in(1, 10).loop( insertInto(T).columns(T.COL).values(i) ) ).execute();
The entire loop is executed on the server, which may greatly help reduce client server round trips.
Apart from the block statement, this feature set is available only in our commercial distributions.
4.7.1. Block statement
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The most basic building block in procedural languages is the block statement, which allows for creating scope (except for T-SQL, which has no block scope), and for logically grouping related statement together. Just like in Java, where any set of statements can be grouped using curly braces: { statment1; statement2; }
, in procedural languages, usually, the keywords BEGIN
and END
are used to delimit a block. For example:
BEGIN INSERT INTO t (col) VALUES (1); INSERT INTO t (col) VALUES (2); END;
create.begin( insertInto(T).columns(T.COL).values(1), insertInto(T).columns(T.COL).values(2) ).execute();
Notice how jOOQ's DSLContext.begin(Statement...) takes an ordinary varargs array (or collection) of org.jooq.Statement
as an argument. As such, the statements are comma separated, not semi colon separated. Also, it is important that statements passed to the procedural API do not call the Query.execute() method, as that would execute a statement in the client, rather than embedding a statement expression in a block.
Just like in SQL, such blocks can be nested with any depth, e.g.
BEGIN BEGIN INSERT INTO t (col) VALUES (1); INSERT INTO t (col) VALUES (2); END; BEGIN INSERT INTO t (col) VALUES (3); INSERT INTO t (col) VALUES (4); END; END;
create.begin( begin( insertInto(T).columns(T.COL).values(1), insertInto(T).columns(T.COL).values(2) ), begin( insertInto(T).columns(T.COL).values(3), insertInto(T).columns(T.COL).values(4) ) ).execute();
Client side "blocks"
In some cases, it may be desireable to group several statements in a "block" in the client only, without producing the BEGIN
and END
keywords on the server, in case it is not needed. This can be done using DSLContext.statements(Statement...).
INSERT INTO t (col) VALUES (1); INSERT INTO t (col) VALUES (2);
statements( insertInto(T).columns(T.COL).values(1), insertInto(T).columns(T.COL).values(2))
This API is useful whenever you want to group several statements into one logical org.jooq.Statement
and let jOOQ figure out if BEGIN .. END
block syntax is required or not. If it is required, then they are added - e.g. when the block is executed on the top level, or nested inside an IF statement, in case the IF
statement doesn't already have its own THEN
keyword to delimit multi-statement content.
Block execution
org.jooq.Block
extends org.jooq.Query
, which in turn extends org.jooq.Statement
. A Query
is a statement that can be executed on its own, as a standalone executable.
All other org.jooq.Statement
types (as explained in the following sections) cannot be executed on their own. For example, it makes no sense to execute a GOTO statement outside of a statement block.
Dialect support
This example using jOOQ:
begin(deleteFrom(BOOK), deleteFrom(AUTHOR))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, POSTGRES, YUGABYTEDB DO $$ BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END; $$ -- BIGQUERY BEGIN DELETE FROM BOOK WHERE TRUE; DELETE FROM AUTHOR WHERE TRUE; END; -- DB2 BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END -- EXASOL, INFORMIX, ORACLE, SQLDATAWAREHOUSE, SQLSERVER, TERADATA, VERTICA BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END; -- FIREBIRD EXECUTE BLOCK AS BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END -- H2 CREATE ALIAS block_1700915558913_8704722 AS $$ void x(Connection c) throws SQLException { try (PreparedStatement s = c.prepareStatement( "DELETE FROM BOOK" )) { s.execute(); } try (PreparedStatement s = c.prepareStatement( "DELETE FROM AUTHOR" )) { s.execute(); } } $$; CALL block_1700915558913_8704722(); DROP ALIAS block_1700915558913_8704722; -- HANA DO BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END; -- HSQLDB BEGIN ATOMIC DELETE FROM BOOK; DELETE FROM AUTHOR; END; -- MARIADB BEGIN NOT ATOMIC DELETE FROM BOOK; DELETE FROM AUTHOR; END; -- MYSQL CREATE PROCEDURE block_1700915565472_4657672() MODIFIES SQL DATA BEGIN DELETE FROM BOOK; DELETE FROM AUTHOR; END; CALL block_1700915565472_4657672(); DROP PROCEDURE block_1700915565472_4657672; -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TRINO /* UNSUPPORTED */
4.7.2. CALL statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When using CREATE PROCEDURE statements, for greater composability, it is essential to be able to call a procedure from another procedure. This is done using the CALL
statement.
// Create a procedure that inserts a log message in a table Parameter<String> message = in("message", VARCHAR); create.createProcedure("log") .parameters(message) .as(insertInto(LOG).columns(LOG.TEXT).values(message)) .execute(); create.createProcedure("some_other_procedure") .as( // ... call("log").args(val("My first message")), // ... call("log").args(val("My second message")) // ... ) .execute();
Dialect support
This example using jOOQ:
call("log").args(val("message"))
Translates to the following dialect specific expressions:
-- BIGQUERY, DB2, HANA, HSQLDB, MARIADB, MYSQL, POSTGRES, YUGABYTEDB CALL log('message') -- FIREBIRD, INFORMIX EXECUTE PROCEDURE log('message') -- ORACLE BEGIN log('message'); END; -- SQLDATAWAREHOUSE, SQLSERVER EXEC log 'message' -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, MEMSQL, REDSHIFT, SNOWFLAKE, -- SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.3. CONTINUE statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A safer way to jump to labels than via GOTO is to use EXIT (jumping out of a LOOP, or block, or other statement) or CONTINUE (skipping a LOOP iteration).
Just like Java's continue
, the CONTINUE
statement skips the rest of the current iteration in a loop and continues the next iteration. Some dialects use the ITERATE
statement for this.
Without a label
-- PL/SQL LOOP i := i + 1; CONTINUE WHEN i <= 10; END LOOP;
// All dialects loop( i.set(i.plus(1)), continueWhen(i.gt(10)) )
With a label
-- PL/SQL <<label>> LOOP i := i + 1; CONTINUE label WHEN i <= 10; END LOOP;
// All dialects Label label = label("label"); label.label(loop( i.set(i.plus(1)), continue(label).when(i.le(10)) ))
Notice that continue
is a reserved keyword in the Java language, so the jOOQ API cannot use it as a method name. We've suffixed such conflicts with an underscore: continue_()
.
Dialect support
This example using jOOQ:
loop(i.set(i.plus(1)), continueWhen(i.gt(10)))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES LOOP SET i = (i + 1); CONTINUE WHEN i > 10; END LOOP -- BIGQUERY LOOP SET i = (i + 1); IF i > 10 THEN CONTINUE; END IF; END LOOP -- DB2, HSQLDB, MARIADB, MYSQL alias_1: LOOP SET i = (i + 1); IF i > 10 THEN ITERATE alias_1; END IF; END LOOP -- H2 for (;;) { i = (i + 1); if (i > 10) { continue; } } -- HANA WHILE 1 = 1 DO i = (i + 1); IF i > 10 THEN CONTINUE; END IF; END WHILE -- INFORMIX LOOP LET i = (i + 1); IF i > 10 THEN CONTINUE; END IF; END LOOP -- ORACLE, POSTGRES, YUGABYTEDB LOOP i := (i + 1); CONTINUE WHEN i > 10; END LOOP -- SQLDATAWAREHOUSE, SQLSERVER WHILE 1 = 1 BEGIN SET @i = (@i + 1); IF @i > 10 CONTINUE; END -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, -- TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.4. EXECUTE statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Many dialects support some way of running dynamic SQL from procedural code. For this, the EXECUTE
or EXECUTE IMMEDIATE
statements can be used.
In some dialects (e.g. Oracle PL/SQL), using EXECUTE
is the only way to run DDL from procedural code.
For example:
-- PL/SQL BEGIN EXECUTE IMMEDIATE 'CREATE TABLE t (col int)'; END;
// All dialects create.begin( execute(createTable("t").column("col", INTEGER).getSQL()) ).excute();
You could obviously just pass an arbitrary string to the EXECUTE
statement, as in PL/SQL, but the above example shows how to use this approach also with dynamically created jOOQ statements, by calling Query.getSQL().
Dialect support
This example using jOOQ:
execute("create table t (i int)")
Translates to the following dialect specific expressions:
-- BIGQUERY, DB2, HANA, MARIADB, ORACLE EXECUTE IMMEDIATE 'create table t (i int)' -- FIREBIRD EXECUTE STATEMENT 'create table t (i int)' -- MYSQL CREATE PROCEDURE block_1700915565474_2469161() MODIFIES SQL DATA BEGIN PREPARE s FROM 'create table t (i int)'; EXECUTE s; DEALLOCATE PREPARE s; END; CALL block_1700915565474_2469161(); DROP PROCEDURE block_1700915565474_2469161; -- POSTGRES, YUGABYTEDB EXECUTE 'create table t (i int)' -- SQLSERVER EXECUTE ('create table t (i int)') -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, COCKROACHDB, DERBY, DUCKDB, EXASOL, H2, HSQLDB, INFORMIX, MEMSQL, REDSHIFT, -- SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.5. EXIT statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A safer way to jump to labels than via GOTO is to use EXIT (jumping out of a LOOP, or block, or other statement) or CONTINUE (skipping a LOOP iteration).
For example, in the absence of more sophisticated LOOP
syntaxes, you may choose to exit a loop using EXIT
(which translates to LEAVE
or BREAK
in some dialects, and works the same way as Java's break
):
Without a label
-- PL/SQL LOOP i := i + 1; EXIT WHEN i > 10; END LOOP;
// All dialects loop( i.set(i.plus(1)), exitWhen(i.gt(10)) )
With a label
-- PL/SQL <<label>> LOOP i := i + 1; EXIT label WHEN i > 10; END LOOP;
// All dialects Label label = label("label"); label.label(loop( i.set(i.plus(1)), exit(label).when(i.gt(10)) ))
Dialect support
This example using jOOQ:
loop(i.set(i.plus(1)), exitWhen(i.gt(10)))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES LOOP SET i = (i + 1); EXIT WHEN i > 10; END LOOP -- BIGQUERY LOOP SET i = (i + 1); IF i > 10 THEN BREAK; END IF; END LOOP -- DB2, HSQLDB, MARIADB, MYSQL alias_1: LOOP SET i = (i + 1); IF i > 10 THEN LEAVE alias_1; END IF; END LOOP -- FIREBIRD WHILE (1 = 1) DO BEGIN :i = (:i + 1); IF (:i > 10) THEN LEAVE; END -- H2 for (;;) { i = (i + 1); if (i > 10) { break; } } -- HANA WHILE 1 = 1 DO i = (i + 1); IF i > 10 THEN BREAK; END IF; END WHILE -- INFORMIX LOOP LET i = (i + 1); EXIT WHEN i > 10; END LOOP -- ORACLE, POSTGRES, YUGABYTEDB LOOP i := (i + 1); EXIT WHEN i > 10; END LOOP -- SQLDATAWAREHOUSE, SQLSERVER WHILE 1 = 1 BEGIN SET @i = (@i + 1); IF @i > 10 BREAK; END -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, EXASOL, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, -- TRINO, VERTICA /* UNSUPPORTED */
4.7.6. FOR statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
When iterating over a sequence of numeric values, the FOR
loop provides useful syntax sugar over the previous types of loops, including the WHILE loop, despite being functional equivalent.
An example:
-- PL/SQL FOR i IN 1 .. 10 LOOP INSERT INTO t (col) VALUES (i); END LOOP;
// All dialects Variable<Integer> i = var("i", INTEGER); for_(i).in(1, 10).loop( insertInto(T).columns(T.COL).values(i) )
In addition to simplifying the most common case, there are also options of traversing the arguments in a reversed way, and using an additional optional step variable, for example:
-- pgplsql FOR i IN REVERSE 10 .. 1 BY 2 LOOP INSERT INTO t (col) VALUES (i); END LOOP;
// All dialects Variable<Integer> i = var("i", INTEGER); for_(i).inReverse(10, 1).by(2).loop( insertInto(T).columns(T.COL).values(i) )
Not all dialects support the entirety of this syntax, but luckily it is easy for jOOQ to emulate in all dialects using WHILE:
-- PL/SQL WHILE i >= 1 LOOP INSERT INTO t (col) VALUES (i); i := i - 2; END LOOP;
Notice that for
is a reserved keyword in the Java language, so the jOOQ API cannot use it as a method name. We've suffixed such conflicts with an underscore: for_()
.
Dialect support
This example using jOOQ:
for_(i).in(1, 10).loop(insertInto(BOOK).columns(BOOK.ID).values(i))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, EXASOL, ORACLE, POSTGRES, YUGABYTEDB FOR i IN 1 .. 10 LOOP INSERT INTO BOOK (ID) VALUES (i); END LOOP -- BIGQUERY BEGIN DECLARE i int64 DEFAULT 1; WHILE i <= 10 DO INSERT INTO BOOK (ID) VALUES (i); SET i = (i + 1); END WHILE; END; -- DB2 BEGIN DECLARE i integer; SET i = 1; WHILE i <= 10 DO INSERT INTO BOOK (ID) VALUES (i); SET i = (i + 1); END WHILE; END; -- FIREBIRD DECLARE i integer DEFAULT 1; WHILE (:i <= 10) DO BEGIN INSERT INTO BOOK (ID) VALUES (:i); :i = (:i + 1); END -- H2 for (Integer i = 1; i <= 10; i++) { try (PreparedStatement s = c.prepareStatement( "INSERT INTO BOOK (ID)\n" + "VALUES (?)" )) { s.setObject(1, i); s.execute(); } } -- HANA BEGIN DECLARE i integer; FOR i IN 1 .. 10 DO INSERT INTO BOOK (ID) VALUES (i); END FOR; END; -- HSQLDB BEGIN ATOMIC DECLARE i int; SET i = 1; WHILE i <= 10 DO INSERT INTO BOOK (ID) VALUES (i); SET i = (i + 1); END WHILE; END; -- INFORMIX BEGIN DEFINE i integer; LET i = 1; FOR i IN (1 TO 10) LOOP INSERT INTO BOOK (ID) VALUES (i); END LOOP; END; -- MARIADB FOR i IN 1 .. 10 DO INSERT INTO BOOK (ID) VALUES (i); END FOR -- MYSQL BEGIN DECLARE i int; SET i = 1; WHILE i <= 10 DO INSERT INTO BOOK (ID) VALUES (i); SET i = (i + 1); END WHILE; END; -- SQLDATAWAREHOUSE BEGIN DECLARE @i int DEFAULT 1; WHILE @i <= 10 BEGIN INSERT INTO BOOK (ID) SELECT @i; SET @i = (@i + 1); END; END; -- SQLSERVER BEGIN DECLARE @i int = 1; WHILE @i <= 10 BEGIN INSERT INTO BOOK (ID) VALUES (@i); SET @i = (@i + 1); END; END; -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, -- VERTICA /* UNSUPPORTED */
4.7.7. GOTO statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Hey, we don't judge anyone. You have your reasons for using this statement.
In the previous section, we introduced labels. Now we make use of them. For instance, to conditionally skip a set of statements. Or to simplify the example, to inconditionally skip them:
-- PL/SQL BEGIN INSERT INTO t (col) VALUES (1); GOTO l1; INSERT INTO t (col) VALUES (2); <<l1>> INSERT INTO t (col) VALUES (3); END;
// All dialects Label l1 = label("l1"); begin( insertInto(T).columns(T.COL).values(1), goto_(l1), insertInto(T).columns(T.COL).values(2), l1.label(insertInto(T).columns(T.COL).values(3)) )
Some dialects (e.g. T-SQL) may implement "full GOTO" in the ways that are generally not really helping readability or maintainability of code, namely the idea that GOTO
can be used to jump into any arbitrary scope that should not be reachable through ordinary control flow. This is not possible in other languages, like PL/SQL, and currently cannot be emulated by jOOQ.
Notice that goto
is a reserved keyword in the Java language, so the jOOQ API cannot use it as a method name. We've suffixed such conflicts with an underscore: goto_()
.
Dialect support
This example using jOOQ:
begin(l.label(insertInto(BOOK).columns(BOOK.ID).values(1)), goto_(l))
Translates to the following dialect specific expressions:
-- DB2 BEGIN l: INSERT INTO BOOK (ID) VALUES (1); GOTO l; END -- INFORMIX, ORACLE BEGIN <<l>> INSERT INTO BOOK (ID) VALUES (1); GOTO l; END; -- SQLDATAWAREHOUSE, SQLSERVER BEGIN l: INSERT INTO BOOK (ID) VALUES (1); GOTO l; END; -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, -- MARIADB, MEMSQL, MYSQL, POSTGRES, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, VERTICA, YUGABYTEDB /* UNSUPPORTED */
4.7.8. IF statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Conditional branching is an essential feature of all languages. Procedural languages support the IF
statement.
There are different styles of IF
statements in dialects, including:
- Requiring a
THEN
clause for the body of a branch, in case of which no BEGIN .. END block is required for multi-statement bodies. - Allowing a dedicated
ELSIF
clause for alternative, nested branches, to avoid nesting. This is mostly a syntax sugar feature only.
In jOOQ, an IF
statement might look as follows:
-- PL/SQL syntax IF i = 0 THEN INSERT INTO a (col) VALUES (1); ELSIF i = 1 THEN INSERT INTO b (col) VALUES (2); ELSE INSERT INTO c (col) VALUES (3); END IF;
// All dialects if_(i.eq(0)).then( insertInto(A).columns(A.COL).values(1) ).elsif(i.eq(1)).then( insertInto(B).columns(B.COL).values(2) ).else_( insertInto(C).columns(C.COL).values(3) )
Notice that both if
and else
are reserved keywords in the Java language, so the jOOQ API cannot use them as method names. We've suffixed such conflicts with an underscore: if_()
and else_()
.
Dialect support
This example using jOOQ:
if_(i.eq(0)).then(deleteFrom(BOOK)).else_(deleteFrom(AUTHOR))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, DB2, EXASOL, HANA, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE, POSTGRES, YUGABYTEDB IF i = 0 THEN DELETE FROM BOOK; ELSE DELETE FROM AUTHOR; END IF -- BIGQUERY IF i = 0 THEN DELETE FROM BOOK WHERE TRUE; ELSE DELETE FROM AUTHOR WHERE TRUE; END IF -- FIREBIRD IF (:i = 0) THEN DELETE FROM BOOK; ELSE DELETE FROM AUTHOR; -- H2 if (i = 0) { try (PreparedStatement s = c.prepareStatement( "DELETE FROM BOOK" )) { s.execute(); } } else { try (PreparedStatement s = c.prepareStatement( "DELETE FROM AUTHOR" )) { s.execute(); } } -- SQLDATAWAREHOUSE, SQLSERVER IF @i = 0 DELETE FROM BOOK; ELSE DELETE FROM AUTHOR; -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, -- VERTICA /* UNSUPPORTED */
4.7.9. Labels
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In imperative languages, labels are essential with simpler cases of loops (e.g. the LOOP statement), with nested loops, or if you must, when using the GOTO statement.
Using jOOQ, you can label any org.jooq.Statement
by using DSL.label():
-- PL/SQL <<label>> BEGIN NULL; END;
// All dialects Label label = label("label"); label.label(begin())
That's a lot of labels.
The main usages of these labels will be discussed in the following sections about, EXIT, and CONTINUE
Dialect support
This example using jOOQ:
l.label(deleteFrom(BOOK))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, INFORMIX, ORACLE, POSTGRES, YUGABYTEDB <<l>> DELETE FROM BOOK -- DB2, FIREBIRD, H2, HSQLDB, MARIADB, MYSQL, SQLDATAWAREHOUSE, SQLSERVER l: DELETE FROM BOOK -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, HANA, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, -- SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.10. LOOP statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Many procedural languages support a condition-less loop, which in its pure form, just loops forever. In order to create an infinite number of records in a table, one might write the following:
-- PL/SQL syntax LOOP INSERT INTO t (col) VALUES (1); END LOOP;
// All dialects loop( insertInto(T).columns(T.COL).values(1) )
An "infinite" loop is usually exited using an EXIT statement.
Dialect support
This example using jOOQ:
loop(update(BOOK_TO_BOOK_STORE).set(BOOK_TO_BOOK_STORE.STOCK, BOOK_TO_BOOK_STORE.STOCK.plus(1)))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, POSTGRES, YUGABYTEDB LOOP UPDATE BOOK_TO_BOOK_STORE SET STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1); END LOOP -- BIGQUERY LOOP UPDATE BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1) WHERE TRUE; END LOOP -- DB2, EXASOL, HSQLDB, INFORMIX, MARIADB, MYSQL, ORACLE LOOP UPDATE BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1); END LOOP -- FIREBIRD WHILE (1 = 1) DO BEGIN UPDATE BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1); END -- H2 for (;;) { try (PreparedStatement s = c.prepareStatement( "UPDATE BOOK_TO_BOOK_STORE\n" + "SET\n" + " BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1)" )) { s.execute(); } } -- HANA WHILE 1 = 1 DO UPDATE BOOK_TO_BOOK_STORE FROM BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1); END WHILE -- SQLDATAWAREHOUSE, SQLSERVER WHILE 1 = 1 BEGIN UPDATE BOOK_TO_BOOK_STORE SET BOOK_TO_BOOK_STORE.STOCK = (BOOK_TO_BOOK_STORE.STOCK + 1); END -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, -- VERTICA /* UNSUPPORTED */
4.7.11. REPEAT statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
WHILE's lesser known little sibling is REPEAT
, which works the same way as Java's do
statement. It is mostly not as useful as WHILE
, but can be, occasionally, when a loop must be iterated at least once.
An example:
-- MySQL syntax REPEAT INSERT INTO t (col) VALUES (i); SET i = i + 1; UNTIL i > 10 END REPEAT;
// All dialects Variable<Integer> i = var("i", INTEGER); repeat( insertInto(T).columns(T.COL).values(i), i.set(i.plus(1)) ).until(i.gt(10))
Dialect support
This example using jOOQ:
repeat(deleteFrom(BOOK).where(BOOK.ID.eq(i)), i.set(i.plus(1))).until(i.gt(10))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES <<alias_2>> LOOP DELETE FROM BOOK WHERE BOOK.ID = i; SET i = (i + 1); EXIT alias_2 WHEN i > 10; END LOOP -- BIGQUERY REPEAT DELETE FROM BOOK WHERE ( BOOK.ID = i AND TRUE ); SET i = (i + 1); UNTIL i > 10 END REPEAT -- DB2, HSQLDB, MARIADB, MYSQL REPEAT DELETE FROM BOOK WHERE BOOK.ID = i; SET i = (i + 1); UNTIL i > 10 END REPEAT -- EXASOL REPEAT DELETE FROM BOOK WHERE BOOK.ID = i; i := (i + 1); UNTIL i > 10 END REPEAT -- FIREBIRD alias_2: WHILE (1 = 1) DO BEGIN DELETE FROM BOOK WHERE BOOK.ID = :i; :i = (:i + 1); IF (:i > 10) THEN LEAVE alias_2; END -- H2 do { try (PreparedStatement s = c.prepareStatement( "DELETE FROM BOOK\n" + "WHERE BOOK.ID = ?" )) { s.setObject(1, i); s.execute(); } i = (i + 1); } while (!(i > 10)) -- HANA WHILE 1 = 1 DO DELETE FROM BOOK WHERE BOOK.ID = i; i = (i + 1); IF i > 10 THEN BREAK; END IF; END WHILE -- INFORMIX <<alias_2>> LOOP DELETE FROM BOOK WHERE BOOK.ID = i; LET i = (i + 1); EXIT alias_2 WHEN i > 10; END LOOP -- ORACLE, POSTGRES, YUGABYTEDB <<alias_2>> LOOP DELETE FROM BOOK WHERE BOOK.ID = i; i := (i + 1); EXIT alias_2 WHEN i > 10; END LOOP -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, -- SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.12. SIGNAL
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The standard SQL way to raise exceptions is via the SIGNAL
statement, which is supported natively in a few dialects, and can be emulated in some others.
Some example SIGNAL
invocations.
begin(signalSQLState("45000")).execute(); begin(signalSQLState("45000").setMessageText("Custom message")).execute();
Dialect support
This example using jOOQ:
signalSQLState("45000").setMessageText("Custom message")
Translates to the following dialect specific expressions:
-- DB2, HSQLDB, MARIADB, MYSQL SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = 'Custom message' -- HANA SIGNAL SQL_ERROR_CODE '45000' SET MESSAGE_TEXT = 'Custom message' -- POSTGRES, YUGABYTEDB RAISE SQLSTATE '45000' USING MESSAGE = 'Custom message' -- ACCESS, ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, INFORMIX, -- MEMSQL, ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, VERTICA /* UNSUPPORTED */
4.7.13. Variables
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
In imperative languages, local variables are an essential way of temporarily storing data for further processing. All procedural languages have a way to declare, assign, and reference such local variables.
Declaration
In jOOQ, local variable expressions can be created using DSL.var() (not to be confused with DSL.val(T), which creates bind values!)
Variable<Integer> i = var("i", INTEGER);
This variable doesn't do anything on its own yet. But like many things in jOOQ, it has to be declared first, outside of an actual jOOQ expression, in order to be usable in jOOQ expressions.
We can now reference the variable in a declaration statement as follows:
-- MySQL syntax DECLARE i INTEGER;
// All dialects declare(i)
Notice that there are many different ways to declare a local variable in different dialects. There is
The Oracle PL/SQL, PostgreSQL pgplsql style
In these languages, the DECLARE
statement is actually not an independent statement that can be used anywhere. It is part of a procedural block, prepended to BEGIN .. END
:
-- PL/SQL syntax DECLARE i INT; BEGIN NULL; END;
When using jOOQ, you can safely ignore this fact, and prepend that there is a DECLARE
statement also in these dialects. jOOQ will add additional BEGIN .. END
blocks to your surrounding block, to make sure the whole block becomes syntactically and semantically correct.
The T-SQL, MySQL style
In these languages, the DECLARE
statement is really an independent statement that can be used anywhere. Just like in the Java language, variables can be declared at any position and used only "further down", lexically. Ignoring T-SQL's JavaScript-esque understanding of scope for a moment.
-- T-SQL syntax DECLARE @i INTEGER;
Notice that you can safely ignore the @
sign that is required in some dialects, such as T-SQL. jOOQ will generate it for you.
Assignment
A local variable needs a way to have a value assigned to it. Assignments are possible both on org.jooq.Variable
, or on org.jooq.Declaration
, directly. For example
-- T-SQL syntax DECLARE @i INTEGER = 1;
// All dialects declare(i).set(1)
Alternatively, you can split declaration and assignment, or re-assign new values to variables:
-- T-SQL syntax DECLARE @i INTEGER; SET @i = 1; SET @i = 2;
// All dialects declare(i), i.set(1), i.set(2)
Some dialects also support using subqueries in assignment expressions, and other expresions in their procedural languages. For example:
-- T-SQL syntax SET @i = (SELECT MAX(col) FROM t);
// All dialects i.set(select(max(T.COL)).from(T))
The above is equivalent to this:
-- PL/SQL syntax SELECT MAX(col) INTO i FROM t;
// All dialects select(max(T.COL)).into(i).from(T)
Row assignment
Some dialects support row assignment of variables, which other languages call "destructuring". This is particularly useful when assigning multiple values from a query:
-- HSQLDB syntax SET (i, j) = (SELECT MIN(col), MAX(col) FROM t);
// All dialects row(i, j).set(select(min(T.COL), max(T.COL)).from(T))
The above is equivalent to this:
-- PL/SQL syntax SELECT MIN(col), MAX(col) INTO i, j FROM t;
// All dialects select(min(T.COL), max(T.COL)).into(i, j).from(T)
Referencing
Obviously, once we've assigned a value to a local variable, we want to reference it as well in arbitrary expressions, and queries.
For this purpose, org.jooq.Variable
extends org.jooq.Field
, and as such, can be used in arbitrary places where any other column expression can be used. Within the procedural language, a simple example would be to increment a local variable:
-- PL/SQL syntax i := i + 1;
// All dialects i.set(i.plus(1))
Or in a more complete example, use it in a SQL statement:
-- PL/SQL syntax DECLARE i INT; BEGIN i := 1; INSERT INTO t (col) VALUES (i); END;
// All dialects Variable<Integer> i = var("i", INTEGER); create.begin( declare(i), i.set(1), insertInto(T).columns(T.COL).values(i) ).execute();
Dialect support
This example using jOOQ:
begin(declare(i), i.set(1))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES DO $$ DECLARE DECLARE i int; BEGIN SET i = 1; END; $$ -- BIGQUERY BEGIN DECLARE i int64; SET i = 1; END; -- DB2 BEGIN DECLARE i integer; SET i = 1; END -- EXASOL BEGIN i int; i := 1; END; -- FIREBIRD EXECUTE BLOCK AS DECLARE i integer; BEGIN :i = 1; END -- H2 CREATE ALIAS block_1700915558923_7192573 AS $$ void x(Connection c) throws SQLException { Integer i = null; i = 1; } $$; CALL block_1700915558923_7192573(); DROP ALIAS block_1700915558923_7192573; -- HANA DO BEGIN DECLARE i integer; i = 1; END; -- HSQLDB BEGIN ATOMIC DECLARE i int; SET i = 1; END; -- INFORMIX BEGIN DEFINE i integer; LET i = 1; END; -- MARIADB BEGIN NOT ATOMIC DECLARE i int; SET i = 1; END; -- MYSQL CREATE PROCEDURE block_1700915565478_391972() MODIFIES SQL DATA BEGIN DECLARE i int; SET i = 1; END; CALL block_1700915565478_391972(); DROP PROCEDURE block_1700915565478_391972; -- ORACLE DECLARE i number(10); BEGIN i := 1; END; -- POSTGRES, YUGABYTEDB DO $$ DECLARE i int; BEGIN i := 1; END; $$ -- SQLDATAWAREHOUSE, SQLSERVER BEGIN DECLARE @i int; SET @i = 1; END; -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, -- VERTICA /* UNSUPPORTED */
4.7.14. WHILE statement
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
One of the most commonly used loop types is the WHILE
statement, which in its procedural form works just like a Java while
statement with slightly different syntax.
Procedural dialects may or may not use the LOOP
keyword to delimite the loop body, just as with the previous LOOP statement. The jOOQ API always uses it for DSL design reasons. For example, combining the WHILE
loop with the variable assignment statement:
-- PL/SQL syntax WHILE i <= 10 LOOP INSERT INTO t (col) VALUES (i); END LOOP;
// All dialects Variable<Integer> i = var("i", INTEGER); while_(i.le(10)).loop( insertInto(T).columns(T.COL).values(i) )
Notice that while
is a reserved keyword in the Java language, so the jOOQ API cannot use it as a method name. We've suffixed such conflicts with an underscore: while_()
.
Dialect support
This example using jOOQ:
while_(i.le(10)).loop(deleteFrom(BOOK).where(BOOK.ID.eq(i)))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, EXASOL, INFORMIX, ORACLE, POSTGRES, YUGABYTEDB WHILE i <= 10 LOOP DELETE FROM BOOK WHERE BOOK.ID = i; END LOOP -- BIGQUERY WHILE i <= 10 DO DELETE FROM BOOK WHERE ( BOOK.ID = i AND TRUE ); END WHILE -- DB2, HANA, HSQLDB, MARIADB, MYSQL WHILE i <= 10 DO DELETE FROM BOOK WHERE BOOK.ID = i; END WHILE -- FIREBIRD WHILE (:i <= 10) DO BEGIN DELETE FROM BOOK WHERE BOOK.ID = :i; END -- H2 while (i <= 10) { try (PreparedStatement s = c.prepareStatement( "DELETE FROM BOOK\n" + "WHERE BOOK.ID = ?" )) { s.setObject(1, i); s.execute(); } } -- SQLDATAWAREHOUSE, SQLSERVER WHILE @i <= 10 BEGIN DELETE FROM BOOK WHERE BOOK.ID = @i; END -- ACCESS, ASE, AURORA_MYSQL, COCKROACHDB, DERBY, DUCKDB, MEMSQL, REDSHIFT, SNOWFLAKE, SQLITE, SYBASE, TERADATA, TRINO, -- VERTICA /* UNSUPPORTED */
4.8. Catalog and schema expressions
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most databases know some sort of namespace to group objects like tables, stored procedures, sequences and others into a common catalog or schema. jOOQ uses the types org.jooq.Catalog
and org.jooq.Schema
to model these groupings, following SQL standard naming.
The catalog
A catalog is a collection of schemas. In many databases, the catalog corresponds to the database, or the database instance. Most often, catalogs are completely independent and their tables cannot be joined or combined in any way in a single query. The exception here is SQL Server and Sybase ASE, which allow for fully referencing tables from multiple catalogs:
SELECT * FROM [Catalog1].[Schema1].[Table1] AS [t1] JOIN [Catalog2].[Schema2].[Table2] AS [t2] ON [t1].[ID] = [t2].[ID]
Some dialects, including MariaDB, MemSQL, MySQL, use catalogs (databases) and schemas as the same thing. jOOQ treats databases in those dialects as schemas instead.
By default, the Settings.renderCatalog
flag is turned on. In case a database supports querying multiple catalogs, jOOQ will generate fully qualified object names, including catalog name. For more information about this setting, see the manual's section about settings
jOOQ's code generator generates subpackages for each catalog.
The schema
A schema is a collection of objects, such as tables. Most databases support some sort of schema (except for some embedded databases like Access, Firebird, SQLite). In most databases, the schema is an independent structural entity. In Oracle, the schema and the user / owner is mostly treated as the same thing. An example of a query that uses fully qualified tables including schema names is:
SELECT * FROM "Schema1"."Table1" AS "t1" JOIN "Schema2"."Table2" AS "t2" ON "t1"."ID" = "t2"."ID"
By default, the Settings.renderSettings
flag is turned on. jOOQ will thus generate fully qualified object names, including the setting name. For more information about this setting, see the manual's section about settings
4.9. Table expressions
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The following sections explain the various types of table expressions supported by jOOQ
4.9.1. Generated Tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Most of the times, when thinking about a table expression you're probably thinking about an actual table in your database schema. If you're using jOOQ's code generator, you will have all tables from your database schema available to you as type safe Java objects. You can then use these tables in SQL FROM clauses, JOIN clauses or in other SQL statements, just like any other table expression. An example is given here:
SELECT * FROM AUTHOR -- Table expression AUTHOR JOIN BOOK -- Table expression BOOK ON (AUTHOR.ID = BOOK.AUTHOR_ID)
create.select() .from(AUTHOR) // Table expression AUTHOR .join(BOOK) // Table expression BOOK .on(AUTHOR.ID.eq(BOOK.AUTHOR_ID)) .fetch();
The above example shows how AUTHOR and BOOK tables are joined in a SELECT statement. It also shows how you can access table columns by dereferencing the relevant Java attributes of their tables.
See the manual's section about generated tables for more information about what is really generated by the code generator
4.9.2. Aliased Tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The following sections illustrate how to alias tables, their columns, and how to reference columns from aliased tables.
Regardless of how the aliased table is defined, the same aliased table instance is rendered differently depending on where it is placed in the jOOQ expression tree. See the manual's section about rendering declarations vs references for more details.
4.9.2.1. Aliased generated tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The strength of jOOQ's code generator becomes more obvious when you perform table aliasing and dereference fields from generated aliased tables. This can best be shown by example:
-- Select all books by authors born after 1920, -- named "Paulo" from a catalogue: SELECT * FROM author a JOIN book b ON a.id = b.author_id WHERE a.year_of_birth > 1920 AND a.first_name = 'Paulo' ORDER BY b.title
// Declare your aliases before using them in SQL: Author a = AUTHOR.as("a"); Book b = BOOK.as("b"); // Use aliased tables in your statement create.select() .from(a) .join(b).on(a.ID.eq(b.AUTHOR_ID)) .where(a.YEAR_OF_BIRTH.gt(1920) .and(a.FIRST_NAME.eq("Paulo"))) .orderBy(b.TITLE) .fetch();
As you can see in the above example, calling as()
on generated tables returns an object of the same type as the table. This means that the resulting object can be used to dereference fields from the aliased table. This is quite powerful in terms of having your Java compiler check the syntax of your SQL statements. If you remove a column from a table, dereferencing that column from that table alias will cause compilation errors.
4.9.2.2. Aliased table expressions
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Only few types of table expressions can leverage code generation to provide the SQL syntax typesafety shown previously, where generated tables are used. All tables, however, allow for dereferencing their fields through Table::field
methods:
// "Type-unsafe" aliased table: Table<?> a = AUTHOR.as("a"); // Get fields from a: Field<?> id = a.field("ID"); Field<?> firstName = a.field("FIRST_NAME");
The same is true for derived tables, including unnamed derived tables whose synthetic table name is generated by jOOQ:
Table<?> named = table(select(AUTHOR.ID).from(AUTHOR)).as("t"); Table<?> unnamed = table(select(AUTHOR.ID).from(AUTHOR)); Field<?> id = named.field("ID"); // Produces a t.ID reference Field<?> id = unnamed.field("ID"); // Produces a <generated-alias>.ID reference
Note that if you know that the ID
column is of the same type as the AUTHOR.ID
column, you can use that again to dereference the column as is explained again in the section dereferencing table columns.
// Now with inferred Integer type Field<Integer> id = named.field(AUTHOR.ID); // Produces a t.ID reference Field<Integer> id = unnamed.field(AUTHOR.ID); // Produces a <generated-alias>.ID reference
4.9.2.3. Derived column lists
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies how a table can be renamed / aliased in one go along with its columns. It references the term "derived column list" for the following syntax:
SELECT t.a, t.b FROM ( SELECT 1, 2 ) t(a, b)
This feature is useful in various use-cases where column names are not known in advance (but the table's degree is!). An example for this are unnested tables, or the VALUES() table constructor:
-- Unnested tables SELECT t.a, t.b FROM unnest(my_table_function()) t(a, b) -- VALUES() constructor SELECT t.a, t.b FROM VALUES(1, 2),(3, 4) t(a, b)
Only few databases really support such a syntax, but fortunately, jOOQ can emulate it easily using UNION ALL
and an empty dummy record specifying the new column names. The two statements are equivalent:
-- Using derived column lists SELECT t.a, t.b FROM ( SELECT 1, 2 ) t(a, b) -- Using UNION ALL and a dummy record SELECT t.a, t.b FROM ( SELECT null a, null b FROM DUAL WHERE 1 = 0 UNION ALL SELECT 1, 2 FROM DUAL ) t
In jOOQ, you would simply specify a varargs list of column aliases as such:
// Unnested tables create.select().from(unnest(myTableFunction()).as("t", "a", "b")).fetch(); // VALUES() constructor create.select().from(values( row(1, 2), row(3, 4) ).as("t", "a", "b")) .fetch();
Dialect support
This example using jOOQ:
selectFrom(values(row(1, 2)).as("t", "a", "b"))
Translates to the following dialect specific expressions:
-- ACCESS SELECT t.a, t.b FROM ( SELECT 1 a, 2 b FROM ( SELECT count(*) dual FROM MSysResources ) AS dual ) t -- ASE, REDSHIFT, SQLDATAWAREHOUSE, VERTICA SELECT t.a, t.b FROM ( SELECT 1, 2 ) t (a, b) -- AURORA_MYSQL, MEMSQL SELECT t.a, t.b FROM ( SELECT 1 a, 2 b FROM DUAL ) t -- AURORA_POSTGRES, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, H2, HSQLDB, ORACLE, POSTGRES, SNOWFLAKE, SQLSERVER, TRINO, -- YUGABYTEDB SELECT t.a, t.b FROM ( VALUES (1, 2) ) t (a, b) -- BIGQUERY SELECT t.a, t.b FROM ( SELECT null a, null b FROM UNNEST([STRUCT(1 AS dual)]) AS dual WHERE FALSE UNION ALL SELECT * FROM UNNEST ([ STRUCT (1, 2)]) t ) t -- FIREBIRD SELECT t.a, t.b FROM ( SELECT 1, 2 FROM RDB$DATABASE ) t (a, b) -- HANA SELECT t.a, t.b FROM ( SELECT 1 a, 2 b FROM SYS.DUMMY ) t -- INFORMIX SELECT t.a, t.b FROM ( TABLE (MULTISET { ROW (1, 2)}) ) t (a, b) -- MARIADB SELECT t.a, t.b FROM ( SELECT 1 a, 2 b ) t -- MYSQL SELECT t.a, t.b FROM ( VALUES ROW (1, 2) ) t (a, b) -- SQLITE SELECT t.a, t.b FROM ( SELECT null a, null b WHERE 1 = 0 UNION ALL SELECT * FROM ( VALUES (1, 2) ) t ) t -- SYBASE SELECT t.a, t.b FROM ( SELECT 1, 2 FROM SYS.DUMMY ) t (a, b) -- TERADATA SELECT t.a, t.b FROM ( SELECT 1, 2 FROM ( SELECT 1 AS "dual" ) AS "dual" ) t (a, b)
4.9.2.4. Unnamed derived tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The org.jooq.Table
type can reference a derived table:
-- Derived table (SELECT 1 AS a)
// Derived table table(select(inline(1).as("a")));
Most databases do not support unnamed derived tables, they require an explicit alias. If you do not provide jOOQ with such an explicit alias, an alias will be generated based on the derived table's content, to make sure the generated SQL will be syntactically correct. The generated alias is not specified and should not be referenced explicitly.
While the actual alias shouldn't be relied upon, as the generation algorithm might change between jOOQ versions, the alias will remain stable per SQL content of the derived table, in order to prevent execution plan cache contention in dialects with an execution plan. In other words, two consecutive renderings of a structurally identical derived table should produce the same generated alias. Of course, it's usually better to provide an explicit alias nonetheless.
4.9.3. Joined tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The JOIN operators that can be used in SQL SELECT statements are the most powerful and best supported means of creating new table expressions in SQL.
This section will explain the different types of join:
-
CROSS JOIN
: A cross product -
INNER JOIN
: A cross product filtering on matches -
OUTER JOIN
: A cross product filtering on matches, additionally producing some unmatched rows -
SEMI JOIN
: A check for existence of rows from one table in another table (usingEXISTS
orIN
) -
ANTI JOIN
: A check for non-existence of rows from one table in another table (usingNOT EXISTS
or some conditionsNOT IN
)
... as well as the different types of forming join predicates:
-
ON
: Expressing join predicates explicitly -
ON KEY
: Expressing join predicates explicitly or implicitly based on aFOREIGN KEY
-
USING
: Expressing join predicates implicitly based on an explicit set of shared column names in both tables -
NATURAL
: Expressing join predicates implicitly based on an implicit set of shared column names in both tables
... and then, there are additional ways to enrich joins:
-
APPLY
orLATERAL
: Ordering the join tree from left to right, allowing the right side to access rows from the left side -
PARTITION BY
onOUTER JOIN
: To fill the gaps in a report that usesOUTER JOIN
All of these approaches are available twice in the jOOQ API:
- On the
org.jooq.Table
API, where they form binary operators - On the SELECT API, where they are offered as convenience in jOOQ's DSL, to tame the parentheses
4.9.3.1. CROSS JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A CROSS JOIN
creates a cartesian product or cross product between the two tables it joins. It does not allow for any join predicates to be specified.
It is an occasionally useful operator in reporting, when every element of one set need to be combined with every element of another set. For example, when you want to produce a report combining employees and weekdays, and then do something with the resulting table:
SELECT EMPLOYEE.NAME, WEEKDAY.NAME FROM EMPLOYEE CROSS JOIN WEEKDAY
create.select(EMPLOYEE.NAME, WEEKDAY.NAME) .from(EMPLOYEE) .crossJoin(WEEKDAY) .fetch();
Some example output might be:
+---------------+--------------+ | EMPLOYEE.NAME | WEEKDAY.NAME | +---------------+--------------+ | Jon | Monday | | Jon | Tuesday | | Jon | Wednesday | | Jon | Thursday | | Jon | Friday | | Jon | Saturday | | Jon | Sunday | | Jane | Monday | | Jane | Tuesday | | Jane | Wednesday | | Jane | Thursday | | Jane | Friday | | Jane | Saturday | | Jane | Sunday | | ... | ... | +---------------+--------------+
Table lists
Note that a CROSS JOIN
is functionally (but not syntactically) equivalent to a table list that you can provide in the FROM clause:
SELECT EMPLOYEE.NAME, WEEKDAY.NAME FROM EMPLOYEE, WEEKDAY
create.select(EMPLOYEE.NAME, WEEKDAY.NAME) .from(EMPLOYEE, WEEKDAY) .fetch();
It is usually recommended to prefer the CROSS JOIN
syntax in order to clearly communicate intent.
Dialect support
This example using jOOQ:
select(BOOK.ID, AUTHOR.ID).from(BOOK.crossJoin(AUTHOR))
Translates to the following dialect specific expressions:
-- ASE SELECT BOOK.ID, AUTHOR.ID FROM BOOK JOIN AUTHOR ON 1 = 1 -- AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, EXASOL, FIREBIRD, H2, HANA, HSQLDB, INFORMIX, -- MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA, TRINO, -- VERTICA, YUGABYTEDB SELECT BOOK.ID, AUTHOR.ID FROM BOOK CROSS JOIN AUTHOR -- ACCESS, DUCKDB /* UNSUPPORTED */
4.9.3.2. INNER JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
An INNER JOIN
or just JOIN
works like a CROSS JOIN, but adds a predicate of some sort filtering out unwanted combinations. This is the most popular way to join tables, as we hardly ever want to combine arbitrary rows from both tables, but the ones that have some relationship with each other, e.g. a FOREIGN KEY
reference match.
SELECT * FROM AUTHOR JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select() .from(AUTHOR) .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The above query will return all authors and their books. True to the nature of an INNER JOIN
, authors without books are excluded as well as books without authors (if the FOREIGN KEY
is optional).
The result might look like this:
+------------+-----------+--------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | | Paulo | Coelho | O Alquimista | | Paulo | Coelho | Brida | +------------+-----------+--------------+
In the example, we're using the ON clause to form the JOIN
predicate, but other options will be discussed in later sections as well.
The INNER
keyword is optional both in SQL and in jOOQ, and does not affect the query semantics at all.
Dialect support
This example using jOOQ:
select(BOOK.ID, AUTHOR.ID).from(BOOK.join(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
Translates to the following dialect specific expressions:
-- ACCESS SELECT BOOK.ID, AUTHOR.ID FROM BOOK INNER JOIN AUTHOR ON BOOK.AUTHOR_ID = AUTHOR.ID -- ASE, AURORA_MYSQL, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DB2, DERBY, DUCKDB, EXASOL, FIREBIRD, H2, HANA, HSQLDB, -- INFORMIX, MARIADB, MEMSQL, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, -- TERADATA, TRINO, VERTICA, YUGABYTEDB SELECT BOOK.ID, AUTHOR.ID FROM BOOK JOIN AUTHOR ON BOOK.AUTHOR_ID = AUTHOR.ID
4.9.3.3. OUTER JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
OUTER JOIN
allows for producing some additional rows when an INNER JOIN does not match. There are 3 types of OUTER JOIN
:
-
LEFT JOIN
orLEFT OUTER JOIN
: Always produce all rows from the left side of the join, and only matched rows from the right side of the join -
RIGHT JOIN
orRIGHT OUTER JOIN
: Always produce all rows from the right side of the join, and only matched rows from the left side of the join -
FULL JOIN
orFULL OUTER JOIN
: Always produce all rows from both left and right side of the join
The OUTER
keyword is optional both in SQL and in jOOQ, and does not affect the query semantics at all.
This is best explained by example.
LEFT JOIN
LEFT JOIN
is the most popular among the OUTER JOIN
types.
The following query produces all authors, and possibly, their books:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE FROM AUTHOR LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE) .from(AUTHOR) .leftJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The result might look like this:
+------------+-----------+--------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | | Paulo | Coelho | O Alquimista | | Paulo | Coelho | Brida | <-- Above rows are also produced by INNER JOIN | Jane | Austen | | <-- This row is only produced by LEFT JOIN or FULL JOIN +------------+-----------+--------------+
As can be seen, all rows from the left side of the join (authors) are produced, including the ones that do not have any matches on the right side of the join (books). We don't have any books for Jane Austen yet, but Jane Austen is in the result set. She wouldn't be if this were an INNER JOIN.
RIGHT JOIN
RIGHT JOIN
is just the inverse of a LEFT JOIN
, and is hardly ever used.
The following query produces all books, and possibly, their authors:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE FROM AUTHOR RIGHT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE) .from(AUTHOR) .rightJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The result might look like this:
+------------+-----------+--------------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | | Paulo | Coelho | O Alquimista | | Paulo | Coelho | Brida | <-- Above rows are also produced by INNER JOIN | | | The Arabian Nights | <-- This row is only produced by RIGHT JOIN or FULL JOIN +------------+-----------+--------------------+
As can be seen, all rows from the right side of the join (books) are produced, including the ones that do not have any matches on the left side of the join (authors). The Arabian Night does not have a specific author, but it is still in the result set. It wouldn't be if this were an INNER JOIN.
Not that a RIGHT JOIN
is just an inversed LEFT JOIN
, and you would be much more likely to write the same query like this, with no semantic difference:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE FROM BOOK LEFT JOIN AUTHOR ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE) .from(BOOK) .leftJoin(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
There are complex join trees where a RIGHT JOIN
may make things simpler, but in most cases, it only complicates readability and maintainability of your query.
FULL JOIN
FULL JOIN
is an occasionally useful way to join two tables when no rows from either table should be omitted. This can be useful e.g. to compare two data sets.
The following query produces all authors and all books:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE FROM AUTHOR FULL JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, BOOK.TITLE) .from(AUTHOR) .fullJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The result might look like this:
+------------+-----------+--------------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | | Paulo | Coelho | O Alquimista | | Paulo | Coelho | Brida | <-- Above rows are also produced by INNER JOIN | Jane | Austen | | <-- This row is only produced by LEFT JOIN or FULL JOIN | | | The Arabian Nights | <-- This row is only produced by RIGHT JOIN or FULL JOIN +------------+-----------+--------------------+
As can be seen, all rows from the left side of the join (authors) as well as from the right side of the join (books) are produced, including the ones that do not have any matches on the respective other side of the join.
Dialect support
This example using jOOQ:
select(BOOK.ID, AUTHOR.ID).from(BOOK.leftJoin(AUTHOR).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)))
Translates to the following dialect specific expressions:
-- All dialects SELECT BOOK.ID, AUTHOR.ID FROM BOOK LEFT OUTER JOIN AUTHOR ON BOOK.AUTHOR_ID = AUTHOR.ID
4.9.3.4. SEMI JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Relational algebra defines a SEMI JOIN
operation that regrettably didn't make it into standard SQL (yet), though it is easy to emulate using the EXISTS predicate or IN predicate, which is what most people are doing.
jOOQ offers a convenient LEFT SEMI JOIN
operator to match the relational algebra semantics. The following query will produce all authors that have books (but doesn't produce any books):
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME FROM AUTHOR WHERE EXISTS ( SELECT * FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID )
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME ) .from(AUTHOR) .leftSemiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The result might look like this:
+------------+-----------+ | FIRST_NAME | LAST_NAME | +------------+-----------+ | George | Orwell | | Paulo | Coelho | +------------+-----------+
Of course, you can form an equivalent query using EXISTS
or IN
as well in jOOQ. It is also possible to achieve SEMI JOIN
semantics by using an INNER JOIN, and possibly the SELECT DISTINCT
clause, but chances are, that query is slower and incorrect (e.g. removing too many distinct rows). A SEMI JOIN
both using jOOQ's convenience syntax or the equivalent SQL emulation using EXISTS
or IN
are semantically more precise and should be preferred.
SEMI JOIN
is the inverse of the ANTI JOIN operator.
Dialect support
This example using jOOQ:
select(AUTHOR.ID).from(AUTHOR).leftSemiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
Translates to the following dialect specific expressions:
-- All dialects SELECT AUTHOR.ID FROM AUTHOR WHERE EXISTS ( SELECT 1 one FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID )
4.9.3.5. ANTI JOIN
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Relational algebra defines a ANTI JOIN
operation that regrettably didn't make it into standard SQL (yet), though it is easy to emulate using the NOT EXISTS predicate. Unlike SEMI JOIN, it is not advised to use the NOT IN predicate to emulate ANTI JOIN
, because that risks being incorrect in the presence of NULL
values, a mistake that can be very subtle and thus hard to find.
jOOQ offers a convenient LEFT ANTI JOIN
operator to match the relational algebra semantics. The following query will produce all authors that have no books:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME FROM AUTHOR WHERE NOT EXISTS ( SELECT * FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID )
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME ) .from(AUTHOR) .leftAntiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
The result might look like this, i.e. we might have an author Jane Austen in our database, but we don't have any books for her yet:
+------------+-----------+ | FIRST_NAME | LAST_NAME | +------------+-----------+ | Jane | Austen | +------------+-----------+
Of course, you can form an equivalent query using NOT EXISTS
as well in jOOQ. It is also possible to achieve ANTI JOIN
semantics by using an LEFT JOIN and a NULL predicate on the anti joined table's primary key placed outside of the ON clause, though that might be a bit esoteric and hard to read:
SELECT AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME FROM AUTHOR LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID WHERE BOOK.ID IS NULL
create.select( AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME) .from(AUTHOR) .leftJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .where(BOOK.ID.isNull()) .fetch();
Think of the LEFT JOIN example result:
+------------+-----------+--------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | | Paulo | Coelho | O Alquimista | | Paulo | Coelho | Brida | <-- Reject all of the above where we have BOOK.ID IS NOT NULL | Jane | Austen | | <-- Keep only this row, where BOOK.ID IS NULL +------------+-----------+--------------+
As can be seen, no DISTINCT
is required to remove duplicates, because there's always only 1 row for an author without books.
ANTI JOIN
is the inverse of the SEMI JOIN operator.
Dialect support
This example using jOOQ:
select(AUTHOR.ID).from(AUTHOR).leftAntiJoin(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID))
Translates to the following dialect specific expressions:
-- All dialects SELECT AUTHOR.ID FROM AUTHOR WHERE NOT EXISTS ( SELECT 1 one FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID )
4.9.3.6. ON clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.
One way to supply this join predicate is the ON
clause, which offers most flexibility. The following example shows how to "equi join" the author and books tables based on their FOREIGN KEY
relationship:
SELECT * FROM AUTHOR JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select() .from(AUTHOR) .join(BOOK).on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
But in most dialects, any type of join predicate is possible in ON
to specify what rows should be produced by the join operation. Note that while for INNER JOIN, the predicates in the ON
clause and the predicates in the WHERE clause have the same effect, this isn't true for all the other join types, including OUTER JOIN, SEMI JOIN, ANTI JOIN. For example, the following query will list all authors and their books, but only if the book was published before the year 1950:
SELECT * FROM AUTHOR LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID AND BOOK.PUBLISHED_IN < 1950
create.select() .from(AUTHOR) .leftJoin(BOOK) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .and(BOOK.PUBLISHED_IN.lt(1950)) .fetch();
The result might look like this:
+------------+-----------+--------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | <-- This author's books were all published before 1950 | Paulo | Coelho | | <-- This author's books were published after 1950 +------------+-----------+--------------+
We still get all the authors, but only the books that fulfil the ON
predicate. This is very different from putting that additional predicate in the WHERE clause:
SELECT * FROM AUTHOR LEFT JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID WHERE BOOK.PUBLISHED_IN < 1950
create.select() .from(AUTHOR) .leftJoin(BOOK) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .where(BOOK.PUBLISHED_IN.lt(1950)) .fetch();
The result might now look like this:
+------------+-----------+--------------+ | FIRST_NAME | LAST_NAME | TITLE | +------------+-----------+--------------+ | George | Orwell | 1984 | | George | Orwell | Animal Farm | <-- This author's books were all published before 1950 +------------+-----------+--------------+
Now the predicate is applied after the join operator, not as a part of the join operator, so it's just an ordinary predicate.
4.9.3.7. ON KEY clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
TheON KEY
clause can quickly produce ambiguities as the implicit key path between two tables in a complex join tree isn't always unique. This can even happen for queries that have worked in the past, but due to newFOREIGN KEY
constraints being added to tables, will stop working. Use this clause with caution!
All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.
One way to supply this join predicate is the ON KEY
clause, which allows for conveniently joining two tables based on their FOREIGN KEY
relationship, assuming the relevant meta data is known to jOOQ via code generation:
SELECT * FROM AUTHOR JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select() .from(AUTHOR) .join(BOOK).onKey() .fetch();
There are different overloads of this onKey()
method. The above one is applicable when there are no ambiguous paths between the two joined tables. If there are several FOREIGN KEY
declarations (e.g. a book has an AUTHOR_ID
and a CO_AUTHOR_ID
), then you can pass the org.jooq.ForeignKey
reference to the method, instead, to resolve the ambiguity.
SELECT * FROM AUTHOR JOIN BOOK ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select() .from(AUTHOR) .join(BOOK).onKey(Keys.FK_BOOK_AUTHOR) .fetch();
A similar way to join between tables by using the FOREIGN KEY
information is implicit JOIN, which offers path-based navigational expressions from child table to parent table. Unlike the ON KEY
syntax, implicit joins will never run into ambiguities.
4.9.3.8. USING clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The USING
clause can quickly produce ambiguities as the column names between two tables in a complex join tree aren't always unique. This can even happen for queries that have worked in the past, but due to new columns being added to tables, will stop working. Use this clause with caution!
All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.
One way to supply this join predicate is the USING
clause, which allows for specifying a set of column names that are common to both tables, based on which to form a join predicate. Assuming we called our AUTHOR.ID
column AUTHOR.AUTHOR_ID
instead:
SELECT * FROM AUTHOR JOIN BOOK USING (AUTHOR_ID)
create.select() .from(AUTHOR) .join(BOOK).using(AUTHOR.AUTHOR_ID) .fetch();
4.9.3.9. NATURAL clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
TheNATURAL KEY
operator can quickly produce ambiguities as the column names between two tables in a complex join tree aren't always unique, nor should they be included in aJOIN
predicate (e.g.LAST_UPDATE
or other technical columns, present on every table). This can even happen for queries that have worked in the past, but due to new columns being added to tables, will stop working. In fact, it's very hard to design a schema to allow for usingNATURAL JOIN
. Use this clause with caution!
All of INNER JOIN, OUTER JOIN, SEMI JOIN, ANTI JOIN require a join predicate.
One way to supply this join predicate is the NATURAL
clause, which works like USING clause, except that it discovers shared column names implicitly from the table metadata. Assuming we called our AUTHOR.ID
column AUTHOR.AUTHOR_ID
instead:
SELECT * FROM AUTHOR NATURAL JOIN BOOK
create.select() .from(AUTHOR) .naturalJoin(BOOK) .fetch();
There is a high risk of ambiguities even in simple join trees, which is why this syntax is hardly ever used. It can be very rarely useful combined with FULL JOIN to form a NATURAL FULL JOIN
, which can create a sort of SQL-style untagged union type between two row types. A bit esoteric for every day usage.
4.9.3.10. LATERAL
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
LATERAL
is a SQL standard table operator to wrap derived tables (or other table expressions, in some dialects), such that the tables and columns declared before the LATERAL
derived table become in scope. See APPLY for an alternative, SQL Server specific syntax.
An example:
SELECT * FROM AUTHOR, -- All previous objects (i.e. AUTHOR) -- are now in scope for the following subquery LATERAL ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID -- AUTHOR is in scope );
DSL.using(configuration) .select() .from( AUTHOR, lateral( select(count() .from(BOOK) .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))) ) ) .fetch();
This is most useful for:
- TOP N per category queries, which are harder to implement otherwise
- Local column variables
- Calling table valued functions on a row-by-row basis
Dialect support
This example using jOOQ:
select().from(AUTHOR, lateral(selectCount().from(BOOK).where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, MYSQL, ORACLE, POSTGRES, SNOWFLAKE, SYBASE, TRINO, YUGABYTEDB SELECT AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, AUTHOR.DATE_OF_BIRTH, AUTHOR.YEAR_OF_BIRTH, AUTHOR.DISTINGUISHED, alias_124651337.count FROM AUTHOR, LATERAL ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID ) alias_124651337 -- SQLDATAWAREHOUSE, SQLSERVER SELECT AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, AUTHOR.DATE_OF_BIRTH, AUTHOR.YEAR_OF_BIRTH, AUTHOR.DISTINGUISHED, alias_124651337.count FROM AUTHOR CROSS APPLY ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID ) alias_124651337 -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, REDSHIFT, -- SQLITE, TERADATA, VERTICA /* UNSUPPORTED */
4.9.3.11. APPLY
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
APPLY
(specifically, CROSS APPLY
or OUTER APPLY
) is the SQL Server specific syntax for the SQL standard LATERAL derived table syntax.
An example:
SELECT * FROM AUTHOR -- All previous objects (i.e. AUTHOR) -- are now in scope for the following subquery CROSS APPLY ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID -- AUTHOR is in scope );
DSL.using(configuration) .select() .from( AUTHOR .crossApply( select(count() .from(BOOK) .where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))) ) ) .fetch();
This is most useful for:
- TOP N per category queries, which are harder to implement otherwise
- Local column variables
- Calling table valued functions on a row-by-row basis
Dialect support
This example using jOOQ:
selectFrom(AUTHOR.crossApply(selectCount().from(BOOK).where(BOOK.AUTHOR_ID.eq(AUTHOR.ID))))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, DB2, FIREBIRD, POSTGRES, SNOWFLAKE, TRINO, YUGABYTEDB SELECT AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, AUTHOR.DATE_OF_BIRTH, AUTHOR.YEAR_OF_BIRTH, AUTHOR.DISTINGUISHED, alias_124651337.count FROM AUTHOR CROSS JOIN LATERAL ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID ) alias_124651337 -- BIGQUERY, ORACLE, SQLDATAWAREHOUSE, SQLSERVER, SYBASE SELECT AUTHOR.ID, AUTHOR.FIRST_NAME, AUTHOR.LAST_NAME, AUTHOR.DATE_OF_BIRTH, AUTHOR.YEAR_OF_BIRTH, AUTHOR.DISTINGUISHED, alias_124651337.count FROM AUTHOR CROSS APPLY ( SELECT count(*) FROM BOOK WHERE BOOK.AUTHOR_ID = AUTHOR.ID ) alias_124651337 -- ACCESS, ASE, AURORA_MYSQL, DERBY, DUCKDB, EXASOL, H2, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, REDSHIFT, SQLITE, -- TERADATA, VERTICA /* UNSUPPORTED */
4.9.3.12. PARTITION BY
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Standard SQL (e.g. implemented by Oracle) ships with a special syntax available for OUTER JOIN clauses. This can be used to fill gaps for simplified analytical calculations. jOOQ only supports putting the PARTITION BY
clause to the right of the OUTER JOIN
clause. The following example will create at least one record per AUTHOR and per existing value in BOOK.PUBLISHED_IN, regardless if an AUTHOR has actually published a book in that year.
SELECT * FROM AUTHOR LEFT OUTER JOIN BOOK PARTITION BY (PUBLISHED_IN) ON BOOK.AUTHOR_ID = AUTHOR.ID
create.select() .from(AUTHOR) .leftOuterJoin(BOOK) .partitionBy(BOOK.PUBLISHED_IN) .on(BOOK.AUTHOR_ID.eq(AUTHOR.ID)) .fetch();
4.9.4. The VALUES() table constructor
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some databases allow for expressing in-memory temporary tables using a VALUES()
constructor. This constructor usually works the same way as the VALUES()
clause known from the INSERT statement or from the MERGE statement. With jOOQ, you can also use the VALUES()
table constructor, to create tables that can be used in a SELECT statement's FROM clause:
SELECT a, b FROM VALUES(1, 'a'), (2, 'b') t(a, b)
create.select() .from(values(row(1, "a"), row(2, "b")).as("t", "a", "b")) .fetch();
Note, that it is usually quite useful to provide column aliases ("derived column lists") along with the table alias for the VALUES()
constructor.
The above statement is emulated by jOOQ for those databases that do not support the VALUES()
constructor, natively (actual emulations may vary):
-- If derived column expressions are supported: SELECT a, b FROM ( SELECT 1, 'a' FROM DUAL UNION ALL SELECT 2, 'b' FROM DUAL ) t(a, b) -- If derived column expressions are not supported: SELECT a, b FROM ( -- An empty dummy record is added to provide column names for the emulated derived column expression SELECT NULL a, NULL b FROM DUAL WHERE 1 = 0 UNION ALL -- Then, the actual VALUES() constructor is emulated SELECT 1, 'a' FROM DUAL UNION ALL SELECT 2, 'b' FROM DUAL ) t
4.9.5. Derived tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A derived table is a nested SELECT in the FROM clause, i.e. it can be used as a table expression. As such, it works differently from a scalar subquery, which is a column expression.
SELECT nested.* FROM ( SELECT AUTHOR_ID, count(*) books FROM BOOK GROUP BY AUTHOR_ID ) nested ORDER BY nested.books DESC
Table<?> nested = create.select(BOOK.AUTHOR_ID, count().as("books")) .from(BOOK) .groupBy(BOOK.AUTHOR_ID).asTable("nested"); create.select(nested.fields()) .from(nested) .orderBy(nested.field("books")) .fetch();
4.9.6. Inline derived tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
An inline derived table is a Table expression with a WHERE clause, both of which can be inlined into the calling query in a lot of cases.
The main use-case for this feature is dynamic SQL, where you can add predicates to tables without call sites noticing, and without giving up on type safety.
Code generation support for inline derived tables was added in jOOQ 3.19, only. The following examples dereferenece columns in a type safe way from generated code. Earlier versions of jOOQ require using Table.field(Field), or a similar method.
-- In SQL, the derived table is inlined SELECT BOOK.ID, BOOK.TITLE FROM BOOK WHERE BOOK.TITLE LIKE 'A%'
// This book reference can be supplied dynamically Book aBooks = BOOK.where(BOOK.TITLE.like("A%")); create.select(aBooks.ID, aBooks.TITLE) .from(aBooks) .fetch();
Whenever the context requires, the inline derived table generates an explicit derived table, e.g. when used in a LEFT JOIN
:
-- In SQL, the derived table created explicitly SELECT BOOK.ID, BOOK.TITLE FROM AUTHOR LEFT JOIN ( SELECT * FROM BOOK WHERE BOOK.TITLE LIKE 'A%' ) BOOK ON AUTHOR.ID = BOOK.AUTHOR_ID
// This book reference can be supplied dynamically Book aBooks = BOOK.where(BOOK.TITLE.like("A%")); create.select(AUTHOR.ID, aBooks.ID, aBooks.TITLE) .from(AUTHOR) .leftJoin(aBooks).on(AUTHOR.ID.eq(aBooks.AUTHOR_ID)) .fetch();
4.9.7. The Oracle 11g PIVOT clause
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
If you are closely coupling your application to an Oracle database, you can take advantage of some Oracle-specific features, such as the PIVOT clause, used for statistical analyses. The formal syntax definition is as follows:
-- SELECT .. FROM table PIVOT (aggregateFunction [, aggregateFunction] FOR column IN (expression [, expression])) -- WHERE ..
The PIVOT clause is available from the org.jooq.Table
type, as pivoting is done directly on a table. Currently, only Oracle's PIVOT clause is supported. Support for SQL Server's slightly different PIVOT clause will be added later. Also, jOOQ may emulate PIVOT for other dialects in the future.
4.9.8. jOOQ's relational division syntax
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
There is one operation in relational algebra that is not given a lot of attention, because it is rarely used in real-world applications. It is the relational division, the opposite operation of the cross product (or, relational multiplication). The following is an approximate definition of a relational division:
Assume the following cross join / cartesian product C = A × B Then it can be said that A = C ÷ B B = C ÷ A
With jOOQ, you can simplify using relational divisions by using the following syntax:
C.divideBy(B).on(C.ID.eq(B.C_ID)).returning(C.TEXT)
The above roughly translates to
SELECT DISTINCT C.TEXT FROM C "c1" WHERE NOT EXISTS ( SELECT 1 FROM B WHERE NOT EXISTS ( SELECT 1 FROM C "c2" WHERE "c2".TEXT = "c1".TEXT AND "c2".ID = B.C_ID ) )
Or in plain text: Find those TEXT values in C whose ID's correspond to all ID's in B. Note that from the above SQL statement, it is immediately clear that proper indexing is of the essence. Be sure to have indexes on all columns referenced from the on(...) and returning(...) clauses.
For more information about relational division and some nice, real-life examples, see
4.9.9. Array and cursor unnesting
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies how SQL databases should implement ARRAY and TABLE types, as well as CURSOR types. Put simply, a CURSOR is a pointer to any materialised table expression. Depending on the cursor's features, this table expression can be scrolled through in both directions, records can be locked, updated, removed, inserted, etc. Often, CURSOR types contain s, whereas ARRAY and TABLE types contain simple scalar values, although that is not a requirement
ARRAY types in SQL are similar to Java's array types. They contain a "component type" or "element type" and a "dimension". This sort of ARRAY type is implemented in H2, HSQLDB and Postgres and supported by jOOQ as such. Oracle uses strongly-typed arrays, which means that an ARRAY type (VARRAY or TABLE type) has a name and possibly a maximum capacity associated with it.
Unnesting array and cursor types
The real power of these types become more obvious when you fetch them from stored procedures to unnest them as table expressions and use them in your FROM clause. An example is given here, where Oracle's DBMS_XPLAN package is used to fetch a cursor containing data about the most recent execution plan:
SELECT * FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(null, null, 'ALLSTATS'));
create.select() .from(table(DbmsXplan.displayCursor(null, null, "ALLSTATS")) .fetch();
Note, in order to access the DbmsXplan package, you can use the code generator to generate Oracle's SYS schema.
4.9.10. Table-valued functions
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some databases support functions that can produce tables for use in arbitrary SELECT statements. jOOQ supports these functions out-of-the-box for such databases. For instance, in SQL Server, the following function produces a table of (ID, TITLE)
columns containing either all the books or just one book by ID:
CREATE FUNCTION f_books (@id INTEGER) RETURNS @out_table TABLE ( id INTEGER, title VARCHAR(400) ) AS BEGIN INSERT @out_table SELECT id, title FROM book WHERE @id IS NULL OR id = @id ORDER BY id RETURN END
The jOOQ code generator will now produce a generated table from the above, which can be used as a SQL function:
// Fetching all books records Result<FBooksRecord> r1 = create.selectFrom(fBooks(null)).fetch(); // Lateral joining the table-valued function to another table using CROSS APPLY: create.select(BOOK.ID, F_BOOKS.TITLE) .from(BOOK.crossApply(fBooks(BOOK.ID))) .fetch();
4.9.11. GENERATE_SERIES
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
A nice built-in table-valued function from the PostgreSQL dialect is the GENERATE_SERIES()
function, which allows for creating a table for a range of numeric values. Many dialects have some way of generating such a table, and if not, it can be emulated using recursive SQL.
// Values from 1 to 10 Result<Record1<Integer>> r = create.selectFrom(generateSeries(1, 10)).fetch();
Dialect support
This example using jOOQ:
selectFrom(generateSeries(1, 10))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, DUCKDB, POSTGRES, YUGABYTEDB SELECT generate_series.generate_series FROM generate_series(1, 10) -- BIGQUERY SELECT generate_series.generate_series FROM ( SELECT null generate_series FROM UNNEST([STRUCT(1 AS dual)]) AS dual WHERE FALSE UNION ALL SELECT * FROM unnest(generate_array(1, 10)) generate_series ) generate_series -- COCKROACHDB SELECT generate_series.generate_series FROM generate_series(1, 10) generate_series (generate_series) -- DB2 SELECT generate_series.generate_series FROM ( WITH generate_series(generate_series) AS ( SELECT 1 FROM SYSIBM.DUAL UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series FROM generate_series ) generate_series -- EXASOL, ORACLE SELECT generate_series.generate_series FROM ( SELECT (level + (1 - 1)) generate_series FROM DUAL CONNECT BY level <= ((10 + 1) - 1) ) generate_series -- FIREBIRD SELECT generate_series.generate_series FROM ( WITH RECURSIVE generate_series(generate_series) AS ( SELECT 1 FROM RDB$DATABASE UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series FROM generate_series ) generate_series -- H2 SELECT generate_series.generate_series FROM system_range(1, 10) generate_series (generate_series) -- HSQLDB SELECT generate_series.generate_series FROM ( WITH RECURSIVE generate_series(generate_series) AS ( SELECT 1 FROM (VALUES(1)) AS dual(dual) UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series FROM generate_series ) generate_series -- INFORMIX SELECT generate_series.generate_series FROM ( SELECT (level + (1 - 1)) generate_series FROM ( SELECT 1 AS dual FROM systables WHERE (tabid = 1) ) AS dual CONNECT BY level <= ((10 + 1) - 1) ) generate_series -- MARIADB, MYSQL, SQLITE, TRINO SELECT generate_series.generate_series FROM ( WITH RECURSIVE generate_series(generate_series) AS ( SELECT 1 UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series FROM generate_series ) generate_series -- SNOWFLAKE SELECT generate_series.generate_series FROM ( SELECT ((seq4() + 1) + (1 - 1)) generate_series FROM TABLE(generator(rowcount => (10 - (1 - 1)))) ) generate_series (generate_series) -- SQLDATAWAREHOUSE WITH generate_series(generate_series) AS ( SELECT 1 UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series.generate_series FROM ( SELECT generate_series FROM generate_series ) generate_series -- SQLSERVER SELECT generate_series.generate_series FROM ( SELECT * FROM generate_series(1, 10) ) generate_series (generate_series) -- SYBASE SELECT generate_series.generate_series FROM ( WITH RECURSIVE generate_series(generate_series) AS ( SELECT 1 FROM SYS.DUMMY UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series FROM generate_series ) generate_series -- TERADATA WITH RECURSIVE generate_series(generate_series) AS ( SELECT 1 FROM ( SELECT 1 AS "dual" ) AS "dual" UNION ALL SELECT (generate_series + 1) FROM generate_series WHERE generate_series < 10 ) SELECT generate_series.generate_series FROM ( SELECT generate_series FROM generate_series ) generate_series -- ACCESS, ASE, AURORA_MYSQL, DERBY, HANA, MEMSQL, REDSHIFT, VERTICA /* UNSUPPORTED */
4.9.12. JSON_TABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some dialects ship with a built-in standard SQL table-valued function called JSON_TABLE
, which can be used to unnest a JSON data structure into a SQL table.
SELECT * FROM json_table( '[{"a":5,"b":{"x":10}},{"a":7,"b":{"y":20}}]', '$[*]' COLUMNS ( id FOR ORDINALITY, a INT, x INT PATH '$.b.x', y INT PATH '$.b.y' ) ) AS t
create.select() .from(jsonTable( JSON.valueOf("[{\"a\":5,\"b\":{\"x\":10}}," + "{\"a\":7,\"b\":{\"y\":20}}]"), "$[*]") .column("id").forOrdinality() .column("a", INTEGER) .column("x", INTEGER).path("$.b.x") .column("y", INTEGER).path("$.b.y") .as("t")) .fetch();
The result would look like this:
+----+---+----+----+ | ID | A | X | Y | +----+---+----+----+ | 1 | 5 | 10 | | | 2 | 7 | | 20 | +----+---+----+----+
4.9.13. XMLTABLE
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
Some dialects ship with a built-in standard SQL table-valued function called XMLTABLE
, which can be used to unnest an XML data structure into a SQL table.
SELECT * FROM xmltable('//row' PASSING '<rows> <row><a>5</a><b><x>10</x></b></row> <row><a>7</a><b><y>20</y></b></row> </rows>' COLUMNS id FOR ORDINALITY, a INT, x INT PATH 'b/x', y INT PATH 'b/y' )
create.select() .from(xmltable("//row") .passing( "<rows>" + "<row><a>5</a><b><x>10</x></b></row>" + "<row><a>7</a><b><y>20</y></b></row>" + "</rows>" ) .column("id").forOrdinality() .column("a", INTEGER) .column("x", INTEGER).path("b/x") .column("y", INTEGER).path("b/y")) .fetch();
The result would look like this:
+----+---+----+----+ | ID | A | X | Y | +----+---+----+----+ | 1 | 5 | 10 | | | 2 | 7 | | 20 | +----+---+----+----+
4.9.14. The DUAL table
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies that the FROM clause is mandatory in a SELECT statement. However, in the real world, there exist three types of databases:
- The ones that always require a
FROM
clause (as required by the SQL standard) - The ones that never require a
FROM
clause (and still allow aWHERE
clause) - The ones that require a
FROM
clause only with aWHERE
clause,GROUP BY
clause, orHAVING
clause
With jOOQ, you don't have to worry about the above distinction of SQL dialects. jOOQ never requires a FROM
clause, but renders the necessary "DUAL"
table, if needed. The following program shows how jOOQ renders "DUAL"
tables
Dialect support
This example using jOOQ:
select(inline(1))
Translates to the following dialect specific expressions:
-- ACCESS SELECT 1 FROM ( SELECT count(*) dual FROM MSysResources ) AS dual -- ASE, AURORA_POSTGRES, BIGQUERY, COCKROACHDB, DUCKDB, EXASOL, H2, MARIADB, MYSQL, ORACLE, POSTGRES, REDSHIFT, SNOWFLAKE, -- SQLDATAWAREHOUSE, SQLITE, SQLSERVER, TRINO, VERTICA, YUGABYTEDB SELECT 1 -- AURORA_MYSQL, MEMSQL SELECT 1 FROM DUAL -- DB2 SELECT 1 FROM SYSIBM.DUAL -- DERBY SELECT 1 FROM SYSIBM.SYSDUMMY1 -- FIREBIRD SELECT 1 FROM RDB$DATABASE -- HANA, SYBASE SELECT 1 FROM SYS.DUMMY -- HSQLDB SELECT 1 FROM (VALUES(1)) AS dual(dual) -- INFORMIX SELECT 1 FROM ( SELECT 1 AS dual FROM systables WHERE (tabid = 1) ) AS dual -- TERADATA SELECT 1 FROM ( SELECT 1 AS "dual" ) AS "dual"
Note, that some databases (H2, MySQL) can normally do without "DUAL"
. However, there exist some corner-cases with complex nested SELECT
statements, where this will cause syntax errors (or parser bugs). To stay on the safe side, jOOQ will always render "dual" in those dialects.
4.9.15. Temporal tables
Applies to ❌ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
SQL:2011 standardised a feature called temporal validity, which comes in two flavours implemented through temporal tables:
- System versioned tables
- Application versioned tables
A few dialects, including DB2, MariaDB, Oracle, SQL Server implement one or the other, or both types of temporal tables through standard or vendor specific syntax.
System versioned tables
A system versioned table can be used for automatic backups or audit logging of all content in a table. Each "version" of a record has a validity period, until the record is updated or deleted, when a new "version" of the record is created.
Consider the following table (please consider your database manual for actual syntax. There are restrictions on data types and on how the history table is managed.):
CREATE TABLE product_price ( product_id BIGINT NOT NULL PRIMARY KEY, price DECIMAL NOT NULL, start_ts TIMESTAMP GENERATED ALWAYS AS ROW START, end_ts TIMESTAMP GENERATED ALWAYS AS ROW END, PERIOD FOR SYSTEM_TIME (start_ts, end_ts) );
A table that is defined using the above (simplified) syntax can now be used in DML statements as follows:
-- At time T1, a new product is created: INSERT INTO product (product_id, price) VALUES (1, 100.00); -- Later, at time T2, the price is updated: UPDATE product SET price = 200.00 WHERE product_id = 1;
create.insertInto(PRODUCT, PRODUCT.PRODUCT_ID, PRODUCT.PRICE) .values(1, new BigDecimal("100.00")) .execute(); create.update(PRODUCT) .set(PRODUCT.PRICE, new BigDecimal("200.00")) .where(PRODUCT.PRODUCT_ID.eq(1)) .execute();
Thanks to system versioning, the UPDATE statement is no longer "destructive", meaning that the original row containing the (1, 100.00)
price information is still available from the archive. We can query the PRODUCT
table and its archive as follows (see example query results further down):
-- 1. Get the current version by default SELECT * FROM product; -- 2. Get the version at a given time SELECT * FROM product FOR system_time AS OF :t1; -- 3. Get several versions overlapping a time range [t1, t2] SELECT * FROM product FOR system_time BETWEEN :t1 AND :t2; -- 4. Get several versions overlapping a time range [t1, t2) SELECT * FROM product FOR system_time FROM :t1 TO :t2; -- 5. Get several versions included in a time range [t1, t2] SELECT * FROM product FOR system_time CONTAINED IN (:t1, :t2); -- 6. Get all versions SELECT * FROM product FOR system_time ALL;
// Get the current version by default create.selectFrom(product).fetch(); create.selectFrom(product.for_( systemTime().asOf(t1) )).fetch(); create.selectFrom(product.for_( systemTime().between(t1).and(t2)) )).fetch(); create.selectFrom(product.for_( systemTime().from(t1).to(t2) )).fetch(); create.selectFrom(product.for_( systemTime().containedIn(t1, t2) )).fetch(); create.selectFrom(product.for_( systemTime().all() )).fetch();
The results of the above queries might look like this:
+----------+------------+-------+----------+--------+ | QUERY_NO | PRODUCT_ID | PRICE | START_TS | END_TS | +----------+------------+-------+----------+--------+ | 1 | 1 | 200 | T2 | | +----------+------------+-------+----------+--------+ +----------+------------+-------+----------+--------+ | QUERY_NO | PRODUCT_ID | PRICE | START_TS | END_TS | +----------+------------+-------+----------+--------+ | 2, 4, 5 | 1 | 100 | T1 | T2 | +----------+------------+-------+----------+--------+ +----------+------------+-------+----------+--------+ | QUERY_NO | PRODUCT_ID | PRICE | START_TS | END_TS | +----------+------------+-------+----------+--------+ | 3, 6 | 1 | 100 | T1 | T2 | | 3, 6 | 1 | 200 | T2 | | +----------+------------+-------+----------+--------+
jOOQ 3.13 only supports the above syntaxes if they are natively supported by the underlying dialect as well. Future jOOQ versions may emulate the syntax also in other dialects, or where a specific clause is not supported.
Application versioned tables
While system versioned tables allow for implementing backups and audit logs, some data is naturally versioned from a business perspective as well. Perhaps, instead of just archiving the pricing information, we may wish to specify a validity range for which a given price was valid on a given product. That way, we can accurately restore the old price on an old period in case we need it for reporting or accounting reasons. The (simplified) syntax is almost the same as with system versioned tables, except that instead of using a "magic" SYSTEM_TIME
period name, we can now use our own (or in case of DB2, use BUSINESS_TIME
). Please look up your dialect's manual again, for exact syntax:
CREATE TABLE product_price ( product_id BIGINT NOT NULL PRIMARY KEY, price DECIMAL NOT NULL, start_ts TIMESTAMP, end_ts TIMESTAMP, PERIOD FOR validity (start_ts, end_ts) );
A table that is defined using the above (simplified) syntax can now be used in DML statements as follows:
-- A new product is created INSERT INTO product (product_id, price) VALUES (1, 100.00); -- For the time between [t1, t2], a discount is applied UPDATE product FOR PORTION OF validity FROM t1 TO t2 SET price = 50.00 WHERE product_id = 1;
create.insertInto(PRODUCT, PRODUCT.PRODUCT_ID, PRODUCT.PRICE) .values(1, new BigDecimal("100.00")) .execute(); create.update(PRODUCT.forPortionOf( period(unquotedName("validity")).from(t1).to(t2))) .set(PRODUCT.PRICE, new BigDecimal("50.00")) .where(PRODUCT.PRODUCT_ID.eq(1)) .execute();
If not combined with system versioning, this is again a destructive UPDATE statement, which is effectively transformed into several statements. The resulting table content now looks like this:
+------------+-------+----------+--------+ | PRODUCT_ID | PRICE | START_TS | END_TS | +------------+-------+----------+--------+ | 1 | 100.0 | | T1 | | 1 | 50.0 | T1 | T2 | | 1 | 100.0 | T2 | | +------------+-------+----------+--------+
Depending on your dialect, you can reuse the previous FOR
clauses in SELECT statements, for example:
-- 2. Get the version at a given time SELECT * FROM product FOR validity AS OF :t1;
create.selectFrom(product.for_( period(unquotedName("validity")).asOf(t1) )).fetch();
Which will produce the value of your attribute(s) given their validity at a given timestamp T1:
+------------+-------+----------+--------+ | PRODUCT_ID | PRICE | START_TS | END_TS | +------------+-------+----------+--------+ | 1 | 50.0 | T1 | T2 | +------------+-------+----------+--------+
4.9.16. Data change delta tables
Applies to ✅ Open Source Edition ✅ Express Edition ✅ Professional Edition ✅ Enterprise Edition
The SQL standard specifies how to turn a DML statement into a table expression that can be used in the FROM clause of a SELECT statement. Other dialects support a RETURNING or OUTPUT clause of some sort to produce the same behaviour, though less powerful.
A data change delta table has two parts:
- The result option (
OLD
,NEW
,FINAL
) - The data change statement, which includes DELETE, INSERT, MERGE, UPDATE
You can thus express a query like the following to return all the inserted data (including DEFAULT
and TRIGGER
generated values):
SELECT * FROM FINAL TABLE ( INSERT INTO BOOK (ID, TITLE) VALUES (1, 'The Book') )
create.select() .from(finalTable( insertInto(BOOK) .columns(BOOK.ID, BOOK.TITLE) .values(1, "The Book") )) .fetch();
Following the restrictions implemented by your dialect, the results of such tables can be further processed, projected, etc.
The semantics of the result options are:
-
OLD
: Access the row data as it was prior to being modified by the data change statement. This does not work for INSERT -
NEW
: Access the row data as it is after being modified by the data change statement, but before anyAFTER TRIGGERS
are fired. This does not work for DELETE -
FINAL
: Access the row data as it is after being modified by the data change statement, and all triggers. The data is in its "final" form. This does not work for DELETE
Dialect support
This example using jOOQ:
select(BOOK.ID).from(finalTable(insertInto(BOOK).columns(BOOK.ID, BOOK.TITLE).values(1, "The Book")))
Translates to the following dialect specific expressions:
-- AURORA_POSTGRES, COCKROACHDB, POSTGRES WITH BOOK AS ( INSERT INTO BOOK (ID, TITLE) VALUES ( 1, 'The Book' ) RETURNING BOOK.ID, BOOK.AUTHOR_ID, BOOK.TITLE, BOOK.PUBLISHED_IN, BOOK.LANGUAGE_ID ) SELECT BOOK.ID FROM BOOK BOOK -- DB2, H2 SELECT BOOK.ID FROM FINAL TABLE ( INSERT INTO BOOK (ID, TITLE) VALUES ( 1, 'The Book' ) ) BOOK -- ACCESS, ASE, AURORA_MYSQL, BIGQUERY, DERBY, DUCKDB, EXASOL, FIREBIRD, HANA, HSQLDB, INFORMIX, MARIADB, MEMSQL, MYSQL, -- ORACLE, REDSHIFT, SNOWFLAKE, SQLDATAWAREHOUSE, SQLITE, SQLSERVER, SYBASE, TERADATA