All versions: 3.12 | 3.11 | 3.10 | Development versions: 3.13

DDLDatabase: Code generation from SQL files

Available in ✅ Open Source Edition   ✅ Express Edition   ✅ Professional Edition   ✅ Enterprise Edition

In many cases, the schema is defined in the form of a SQL script, which can be used with Flyway, or some other database migration tool.

If you have a complete schema definition in a single file, or perhaps a set of incremental files that can reproduce your schema in any SQL dialect, then the DDLDatabase might be the right choice for you. It uses the SQL parser internally and applies all your DDL increments to an in-memory H2 database, in order to produce a replica of your schema prior to reverse engineering it again using ordinary code generation.

For example, the following database.sql script (the sample database from this manual) could be used:

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

While the script uses pretty standard SQL constructs, you may well use some vendor-specific extensions, and even DML statements in between to set up your schema - it doesn't matter. You will simply need to set up your code generation configuration as follows:

XML configuration (standalone and Maven)

<configuration xmlns="http://www.jooq.org/xsd/jooq-codegen-3.12.0.xsd">
  <generator>
    <database>
      <name>org.jooq.meta.extensions.ddl.DDLDatabase</name>
      <properties>
            
        <!-- Specify the location of your SQL script.
             You may use ant-style file matching, e.g. /path/**/to/*.sql
             
             Where:
             - ** matches any directory subtree
             - * matches any number of characters in a directory / file name
             - ? matches a single character in a directory / file name -->
        <property>
          <key>scripts</key>
          <value>src/main/resources/database.sql</value>
        </property>
        
        <!-- The sort order of the scripts within a directory, where:
        
             - semantic: sorts versions, e.g. v-3.10.0 is after v-3.9.0 (default)
             - alphanumeric: sorts strings, e.g. v-3.10.0 is before v-3.9.0
             - flyway: sorts files the same way as flyway does
             - none: doesn't sort directory contents after fetching them from the directory -->
        <property>
          <key>sort</key>
          <value>semantic</value>
        </property>
        
        <!-- The default schema for unqualified objects:

             - public: all unqualified objects are located in the PUBLIC (upper case) schema
             - none: all unqualified objects are located in the default schema (default) 
             
             This configuration can be overridden with the schema mapping feature -->
        <property>
          <key>unqualifiedSchema</key>
          <value>none</value>
        </property>
        
        <!-- The default name case for unquoted objects:
        
             - as_is: unquoted object names are kept unquoted
             - upper: unquoted object names are turned into upper case (most databases)
             - lower: unquoted object names are turned into lower case (e.g. PostgreSQL) -->
        <property>
          <key>defaultNameCase</key>
          <value>as_is</value>
        </property>
      </properties>
    </database>
  </generator>
</configuration>

Programmatic configuration

configuration
  .withGenerator(new Generator(
    .withDatabase(new Database()
      .withName("org.jooq.meta.extensions.ddl.DDLDatabase")
      .withProperties(
        new Property()
          .withKey("scripts")
          .withValue("src/main/resources/database.sql"),
        new Property()
          .withKey("sort")
          .withValue("semantic"),
        new Property()
          .withKey("unqualifiedSchema")
          .withValue("none"),
        new Property()
          .withKey("defaultNameCase")
          .withValue("as_is")))));

Gradle configuration

myConfigurationName(sourceSets.main) {
  generator {
    database {
      name = 'org.jooq.meta.extensions.ddl.DDLDatabase'
      properties {
        property {
          key = 'scripts'
          value = 'src/main/resources/database.sql'
        }
        property {
          key = 'sort'
          value = 'semantic'
        }
        property {
          key = 'unqualifiedSchema'
          value = 'none'
        }
        property {
          key = 'defaultNameCase'
          value = 'as_is'
        }
      }
    }
  }
}

Ignoring unsuppored content

The jOOQ parser supports parsing everything that is representable through the jOOQ API, as well as ignores some well known vendor specific syntax. But RDBMS have a lot more features and syntax that are not known to jOOQ. In this case, you can specify two comment tokens around the SQL syntax that jOOQ should ignore. The tokens are located in ordinary single line or multi line comments, so they do not affect your DDL scripts in any other way. For example:

-- [jooq ignore start]
-- Anything between these two tokens is ignored by the jOOQ parser
CREATE EXTENSION postgis;
-- [jooq ignore stop]

CREATE TABLE a (i INT);
CREATE TABLE b (i INT);

/* [jooq ignore start] */
-- This table will not be generated by jOOQ:
CREATE TABLE c (i INT);
/* [jooq ignore stop] */

The tokens can be overridden, or the feature can be turned off entirely using the following properties:

XML configuration (standalone and Maven)

<configuration xmlns="http://www.jooq.org/xsd/jooq-codegen-3.12.0.xsd">
  <generator>
    <database>
      <name>org.jooq.meta.extensions.ddl.DDLDatabase</name>
      <properties>
            
        <!-- Turn on/off ignoring contents between such tokens. Defaults to true -->
        <property>
          <key>parseIgnoreComments</key>
          <value>true</value>
        </property>
        
        <!-- Change the starting token -->
        <property>
          <key>parseIgnoreCommentStart</key>
          <value>[jooq ignore start]</value>
        </property>
        
        <!-- Change the stopping token -->
        <property>
          <key>parseIgnoreCommentStop</key>
          <value>[jooq ignore stop]</value>
        </property>
      </properties>
    </database>
  </generator>
</configuration>

Programmatic configuration

configuration
  .withGenerator(new Generator(
    .withDatabase(new Database()
      .withName("org.jooq.meta.extensions.ddl.DDLDatabase")
      .withProperties(
        new Property()
          .withKey("parseIgnoreComments")
          .withValue("true"),
        new Property()
          .withKey("parseIgnoreCommentStart")
          .withValue("[jooq ignore start]"),
        new Property()
          .withKey("parseIgnoreCommentStop")
          .withValue("[jooq ignore stop]")))));

Gradle configuration

myConfigurationName(sourceSets.main) {
  generator {
    database {
      name = 'org.jooq.meta.extensions.ddl.DDLDatabase'
      properties {
        property {
          key = 'parseIgnoreComments'
          value = 'true'
        }
        property {
          key = 'parseIgnoreCommentStart'
          value = '[jooq ignore start]'
        }
        property {
          key = 'parseIgnoreCommentStop'
          value = '[jooq ignore stop]'
        }
      }
    }
  }
}

Dependencies

Note that the org.jooq.meta.extensions.ddl.DDLDatabase class is located in an external dependency, which needs to be placed on the classpath of the jOOQ code generator. E.g. using Maven:

<dependency>
  <!-- Use org.jooq            for the Open Source Edition
           org.jooq.pro        for commercial editions, 
           org.jooq.pro-java-8 for commercial editions with Java 8 support,
           org.jooq.pro-java-6 for commercial editions with Java 6 support,
           org.jooq.trial      for the free trial edition 
                 
       Note: Only the Open Source Edition is hosted on Maven Central. 
             Import the others manually from your distribution -->
  <groupId>org.jooq.trial</groupId>
  <artifactId>jooq-meta-extensions</artifactId>
  <version>3.12.3</version>
</dependency>
The jOOQ Logo