
When performing database migrations, we at
Data Geekery recommend using
jOOQ with
Flyway – Database Migrations Made Easy. In this post, 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 and workflow behind the following approach can be summarised as this:
- 1. Database increment
- 2. Database migration
- 3. Code re-generation
- 4. Development
The four steps above can be repeated time and again, every time you need to modify something in your database. More concretely, let’s consider:
- 1. Database increment – You need a new column in your database, so you write the necessary DDL in a Flyway script
- 2. Database migration – This Flyway script is now part of your deliverable, which you can share with all developers who can migrate their databases with it, the next time they check out your change
- 3. Code re-generation – Once the database is migrated, you regenerate all jOOQ artefacts (see code generation), locally
- 4. Development – You continue developing your business logic, writing code against the udpated, generated database schema
0.1. 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.2. 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, 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>
<groupId>org.jooq</groupId>
<artifactId>jooq</artifactId>
<version>3.4.0</version>
</dependency>
<dependency>
<groupId>com.h2database</groupId>
<artifactId>h2</artifactId>
<version>1.4.177</version>
</dependency>
<!-- For improved logging, we'll be using
log4j via slf4j to see what's going
on during migration and code generation -->
<dependency>
<groupId>log4j</groupId>
<artifactId>log4j</artifactId>
<version>1.2.16</version>
</dependency>
<dependency>
<groupId>org.slf4j</groupId>
<artifactId>slf4j-log4j12</artifactId>
<version>1.7.5</version>
</dependency>
<!-- To esnure our code is working, we're
using JUnit -->
<dependency>
<groupId>junit</groupId>
<artifactId>junit</artifactId>
<version>4.11</version>
<scope>test</scope>
</dependency>
0.3. Maven Project Configuration – Plugins
After the dependencies, let’s simply add the Flyway and jOOQ Maven plugins like so. The Flyway plugin:
<plugin>
<groupId>org.flywaydb</groupId>
<artifactId>flyway-maven-plugin</artifactId>
<version>3.0</version>
<!-- Note that we're executing the Flyway
plugin in the "generate-sources" phase -->
<executions>
<execution>
<phase>generate-sources</phase>
<goals>
<goal>migrate</goal>
</goals>
</execution>
</executions>
<!-- Note that we need to prefix the db/migration
path with filesystem: to prevent Flyway
from looking for our migration scripts
only on the classpath -->
<configuration>
<url>${db.url}</url>
<user>${db.username}</user>
<locations>
<location>filesystem:src/main/resources/db/migration</location>
</locations>
</configuration>
</plugin>
The above Flyway Maven plugin configuration will read and execute all database migration scripts from
src/main/resources/db/migration
prior to compiling Java source code. While
the official Flyway documentation suggests that migrations be done in the
compile
phase, the jOOQ code generator relies on such migrations having been done
prior to code generation.
After the Flyway plugin, we’ll add the jOOQ Maven Plugin. For more details, please refer to the
manual’s section about the code generation configuration.
<plugin>
<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_t_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_t_book PRIMARY KEY (id),
CONSTRAINT fk_t_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": <>
[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.5.0-SNAPSHOT: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));
}
}
}
If you run the
mvn clean install
again, the above integration test will now compile and pass!
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 (no offense intended ;-) ):
-- 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 observe 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:\...\AfterMigrationTest.java:[24,19] error: cannot find symbol
[INFO] 1 error
When we go back to our Java integration test, we can immediately see that the TITLE column is still being referenced, but it no longer exists:
public class AfterMigrationTest {
@Test
public void testQueryingAfterMigration() throws Exception {
try (Connection c = DriverManager.getConnection("jdbc:h2:~/flyway-test", "sa", "")) {
Result<?> result =
DSL.using(c)
.select(
AUTHOR.FIRST_NAME,
AUTHOR.LAST_NAME,
BOOK.ID,
BOOK.TITLE
// ^^^^^ This column no longer exists.
// We'll have to rename it to LE_TITRE
)
.from(AUTHOR)
.join(BOOK)
.on(AUTHOR.ID.eq(BOOK.AUTHOR_ID))
.orderBy(BOOK.ID.asc())
.fetch();
assertEquals(4, result.size());
assertEquals(asList(1, 2, 3, 4), result.getValues(BOOK.ID));
}
}
}
Conclusion
This tutorial shows very easily how you can build a rock-solid development process using Flyway and jOOQ to prevent SQL-related errors very early in your development lifecycle – immediately at compile time, rather than in production!

Visit the
Flyway website and the
jOOQ website.
Like this:
Like Loading...
Hello,
I have a question about this. So we like to have one executable (jar/war) for each release. We would not like to have an executable for each environment. How would you change this code so that it can be environment independent? You can implement flyway to run its migrations on application startup. What could you do with JOOQ? I hope that makes sense.
Thanks.
No, sorry :) Would you mind asking this question on the user group, instead? I’m sure it will be interesting for other readers as well, and you might get a better response, too: https://groups.google.com/forum/#!forum/jooq-user