Java 8 Friday: Most Internal DSLs are Outdated


At Data Geekery, we love Java. And as we’re really into jOOQ’s fluent API and query DSL, we’re absolutely thrilled about what Java 8 will bring to our ecosystem.

Java 8 Friday

Every Friday, we’re showing you a couple of nice new tutorial-style Java 8 features, which take advantage of lambda expressions, extension methods, and other great stuff. You’ll find the source code on GitHub.

Most Internal DSLs are Outdated

That’s quite a statement from a vendor of one of the most advanced internal DSLs currently on the market. Let me explain:

Languages are hard

Learning a new language (or API) is hard. You have to understand all the keywords, the constructs, the statement and expression types, etc. This is true both for external DSLs, internal DSLs and “regular” APIs, which are essentially internal DSLs with less fluency.

When using JUnit, people have grown used to using hamcrest matchers. The fact that they’re available in six languages (Java, Python, Ruby, Objective-C, PHP, Erlang) makes them somewhat of a sound choice. As a domain-specific language, they have established idioms that are easy to read, e.g.

assertThat(theBiscuit, equalTo(myBiscuit));
assertThat(theBiscuit, is(equalTo(myBiscuit)));
assertThat(theBiscuit, is(myBiscuit));

When you read this code, you will immediately “understand” what is being asserted, because the API reads like prosa. But learning to write code in this API is harder. You will have to understand:

  • Where all of these methods are coming from
  • What sorts of methods exist
  • Who might have extended hamcrest with custom Matchers
  • What are best practices when extending the DSL

For instance, in the above example, what exactly is the difference between the three? When should I use one and when the other? Is is() checking for object identity? Is equalTo() checking for object equality?

The hamcrest tutorial goes on with examples like these:

public void testSquareRootOfMinusOneIsNotANumber() {
    assertThat(Math.sqrt(-1), is(notANumber()));
}

You can see that notANumber() apparently is a custom matcher, implemented some place in a utility:

public class IsNotANumber
extends TypeSafeMatcher<Double> {

  @Override
  public boolean matchesSafely(Double number) {
    return number.isNaN();
  }

  public void describeTo(Description description) {
    description.appendText("not a number");
  }

  @Factory
  public static <T> Matcher<Double> notANumber() {
    return new IsNotANumber();
  }
}

While this sort of DSL is very easy to create, and probably also a bit fun, it is dangerous to start delving into writing and enhancing custom DSLs for a simple reason. They’re in no way better than their general-purpose, functional counterparts – but they’re harder to maintain. Consider the above examples in Java 8:

Replacing DSLs with Functions

Let’s assume we have a very simple testing API:

static <T> void assertThat(
    T actual, 
    Predicate<T> expected
) {
    assertThat(actual, expected, "Test failed");
}

static <T> void assertThat(
    T actual, 
    Predicate<T> expected, 
    String message
) {
    assertThat(() -> actual, expected, message);
}

static <T> void assertThat(
    Supplier<T> actual, 
    Predicate<T> expected
) {
    assertThat(actual, expected, "Test failed");
}

static <T> void assertThat(
    Supplier<T> actual, 
    Predicate<T> expected, 
    String message
) {
    if (!expected.test(actual.get()))
        throw new AssertionError(message);
}

Now, compare the hamcrest matcher expressions with their functional equivalents:

// BEFORE
// ---------------------------------------------
assertThat(theBiscuit, equalTo(myBiscuit));
assertThat(theBiscuit, is(equalTo(myBiscuit)));
assertThat(theBiscuit, is(myBiscuit));

assertThat(Math.sqrt(-1), is(notANumber()));

// AFTER
// ---------------------------------------------
assertThat(theBiscuit, b -> b == myBiscuit);
assertThat(Math.sqrt(-1), n -> Double.isNaN(n));

With lambda expressions, and a well-designed assertThat() API, I’m pretty sure that you won’t be looking for the right way to express your assertions with matchers any longer.

Note that unfortunately, we cannot use the Double::isNaN method reference, as that would not be compatible with Predicate<Double>. For that, we’d have to do some primitive type magic in the assertion API, e.g.

static void assertThat(
    double actual, 
    DoublePredicate expected
) { ... }

Which can then be used as such:

assertThat(Math.sqrt(-1), Double::isNaN);

Yeah, but…

… you may hear yourself saying, “but we can combine matchers with lambdas and streams”. Yes, of course we can. I’ve just done so now in the jOOQ integration tests. I want to skip the integration tests for all SQL dialects that are not in a list of dialects supplied as a system property:

String dialectString = 
    System.getProperty("org.jooq.test-dialects");

// The string must not be "empty"
assumeThat(dialectString, not(isOneOf("", null)));

// And we check if the current dialect() is
// contained in a comma or semi-colon separated
// list of allowed dialects, trimmed and lowercased
assumeThat(
    dialect().name().toLowerCase(),

    // Another matcher here
    isOneOf(stream(dialectString.split("[,;]"))
        .map(String::trim)
        .map(String::toLowerCase)
        .toArray(String[]::new))
);

… and that’s pretty neat, too, right?

But why don’t I just simply write:

// Using Apache Commons, here
assumeThat(dialectString, StringUtils::isNotEmpty);
assumeThat(
    dialect().name().toLowerCase(),
    d -> stream(dialectString.split("[,;]"))
        .map(String::trim)
        .map(String::toLowerCase())
        .anyMatch(d::equals)
);

No Hamcrest needed, just plain old lambdas and streams!

Now, readability is a matter of taste, of course. But the above example clearly shows that there is no longer any need for Hamcrest matchers and for the Hamcrest DSL. Given that within the next 2-3 years, the majority of all Java developers will be very used to using the Streams API in every day work, but not very used to using the Hamcrest API, I urge you, JUnit maintainers, to deprecate the use of Hamcrest in favour of Java 8 APIs.

Is Hamcrest now considered bad?

Well, it has served its purpose in the past, and people have grown somewhat used to it. But as we’ve already pointed out in a previous post about Java 8 and JUnit Exception matching, yes, we do believe that we Java folks have been barking up the wrong tree in the last 10 years.

The lack of lambda expressions has lead to a variety of completely bloated and now also slightly useless libraries. Many internal DSLs or annotation-magicians are also affected. Not because they’re no longer solving the problems they used to, but because they’re not Java-8-ready. Hamcrest’s Matcher type is not a functional interface, although it would be quite easy to transform it into one. In fact, Hamcrest’s CustomMatcher logic should be pulled up to the Matcher interface, into default methods.

Things dont’ get better with alternatives, like AssertJ, which create an alternative DSL that is now rendered obsolete (in terms of call-site code verbosity) through lambdas and the Streams API.

If you insist on using a DSL for testing, then probably Spock would be a far better choice anyway.

Other examples

Hamcrest is just one example of such a DSL. This article has shown how it can be almost completely removed from your stack by using standard JDK 8 constructs and a couple of utility methods, which you might have in JUnit some time soon, anyway.

Java 8 will bring a lot of new traction into last decade’s DSL debate, as also the Streams API will greatly improve the way we look at transforming or building data. But many current DSLs are not ready for Java 8, and have not been designed in a functional way. They have too many keywords for things and concepts that are hard to learn, and that would be better modelled using functions.

An exception to this rule are DSLs like jOOQ or jRTF, which are modelling actual pre-existing external DSLs in a 1:1 fashion, inheriting all the existing keywords and syntax elements, which makes them much easier to learn in the first place.

What’s your take?

What is your take on the above assumptions? What is your favourite internal DSL, that might vanish or that might be completely transformed in the next five years because it has been obsoleted by Java 8?

Stay tuned for more Java 8 Friday articles here on this blog.

QueryDSL vs. jOOQ. Feature Completeness vs. Now More Than Ever


This week, Timo Westkämper from QueryDSL has announced feature completeness on the QueryDSL user group, along with his call for contributions and increased focus on bugfixes and documentation.

Timo and us, we have always been in close contact, observing each other’s products. In the beginning of jOOQ in 2009, QueryDSL was ahead of us.

But we learned quickly and removed all of our shortcomings such that jOOQ and QueryDSL were quickly at eye level by 2011. Ever since, we have been taking inspiration from one another, as in the end, we have had similar goals. Today, whenever someone is looking for a querying DSL, people tend to recommend either of our tools:

QueryDSL is often a good choice in JPA-based environments, while jOOQ is mostly the best choice in SQL-based environments, although jOOQ has already been given some credit in JPA-based environments as well:

Anyway, today, we’d like to congratulate Timo to his new job, and to QueryDSL’s feature completeness.

jOOQ, on the other hand, is far from feature complete.

jOOQ is what SQLJ should have been from the beginning.

We’re only at the beginning. Java and SQL are the two platforms that are used by most of the developers on this planet. According to db-engines.com, almost every popular DBMS is a SQL-based relational DBMS. According to TIOBE, Java currently ranks #2 among all languages.

We strongly believe that all of these developers are in dire need for better SQL integration into the Java language. While ORMs and JPA are very well integrated, SQL is not, and that is what we are working on. jOOQ will be feature complete when the Java compiler can natively compile actual SQL code and SQL code fragments into jOOQ, which will serve as its backing AST model for further SQL transformation.

Until we reach that goal, we’ll be adding support for more SQL goodness. A small selection of things that we already support, beyond QueryDSL’s “feature completeness”:

  • Table-valued functions
  • PIVOT tables
  • DDL (with jOOQ 3.4)
  • MERGE statement
  • Derived tables and derived column lists
  • Row value expressions
  • Flashback query
  • Window functions
  • Ordered aggregate functions
  • Common table expressions (with jOOQ 3.4)
  • Object-oriented PL/SQL
  • User-defined types
  • Hierarchical SQL
  • Custom SQL transformation
  • 16 supported RDBMS (even MS Access!)
  • … you name it

Our roadmap is full of great ideas. There’s plenty of work, so let’s get going! Join us, your partner for…

jOOQ is the best way to write SQL in Java

What if Developing a Simple Data Management Application Just Took 1-2 Days?


What if developing an application just took 1-2 days?
What if I can create it myself with only 10 clicks?
What if I don’t need you developers anymore?

Said every manager since the beginning of history. This is what all managers dream of. Click click click, next next next, and you’re done! Easy, right? Time-to-market: Zero.

Of course, we engineers tend to sincerely doubt that this is possible

Data transformation and navigation

Let’s have a look at some tech stuff.

ergonAs a personal passion, I have always loved the idea of non-procedural approaches to manipulating data (e.g. SQL or XSLT). One of the best pieces of software I’ve ever seen to manipulate data was used by Ergon, a previous employer of mine and a customer of Data Geekery who has created a tool called JTT – Java Table Tool, a dinosaur written around 15 years ago. It was essentially a live RDBMS schema and data navigation tool written as a Swing desktop application. With only little metadata, this application was then capable of providing overviews of:

  • All the tables that you as a user had access to
  • When clicking on a table, you got an editable list of all the records in that table with standard filtering and grouping options
  • When double-clicking on a record, you got an editable popup with details
  • When clicking on a record, you got a “children” view with tabs for all foreign keys that link to this table. Obviuosly, the tabs were again filled with records, which could be navigated through the same way as the “parent” records
  • Foreign key values were not displayed using technical IDs, but using relevant data from the linked record

… and much much more. All business logic and complex update rules were implemented using triggers and grants and just a little meta data to decide what information is primary and what information is secondary (or hidden). Most of the views obviously also were exportable to CSV, XLS, or PDF.

Ergon used this wonderful JTT for internal purposes only, e.g. for accounting, invoice management, as a CRM, as an HR tool. It pretty much ran the company and it did its job very very well. It was one of the technically most awesome products that I’ve ever seen. So lean, so simple, and so powerful (albeit, the UI… Oh well, Swing).

I pressed the product manager and the sales managers to consider revitalising this gem and to make a webapp from it that can be sold to other software companies as a product. At the time, something like Eclipse RAP might have been a good choice to allow for a hybrid desktop and web UI.

Unfortunately, they never wanted to make a proper product from this tool. So, I have always thought that at some point, I’ll create my own JTT, I’ll sell it and I’ll get rich. A browser-based database schema and data navigation tool that allows you to set up a basic data management software product in virtually 2-3 days, even when running on large schemas.

Too late, it already exists!

So these were our plans. And then I read this InfoQ article (and later on, also this DZone article by Val Huber, the same author).

“Unfortunately,” for me and for Data Geekery, I have come to discover Espresso Logic’s Live Browser, which does exactly that. Ironically, I have already blogged about an Espresso Logic product before, when I had spotted their pretty cool reactive REST API (where here, reactive means that with a simple rule engine, you could model all sorts of Excel-spreadsheet-like data updates).

But this Live Browser indeed tops what I had in mind from my JTT experience. It is actually built on top of the aforementioned reactive REST API, so it inherits all the nice features, such as the “role-based, row/column level read and update permissions”, the reactive programming features, etc. Here’s an example view from their product announcement website:

Another example from the InfoQ article:

As you can see, pretty much all of the JTT features that I’ve mentioned before are available out of the box:

  • Table selection
  • Filtering
  • Detail views
  • Foreign key navigation
  • Child navigation
  • Data manipulation

(Ergon, if you’re reading this: You see? I told you 🙂 )

Consider having this as a general-purpose database inspection tool in your company. As a developer, you can quickly navigate the schema (and the data!) in a way that you will never find in Toad or SQL Developer. Obviuosly, the tools don’t compete, as SQL Developer is a database development tool, whereas Live Browser is more of an actual… well, a live data browser.

This browser could also be used as a prototyping engine to assess whether your database schema really models the business case of your customer – a quick display to verify the requirements. Well, as I said, it is a general purpose data browser, that can be used for virtually any simple use-case.

espresso-companyNow, I have again signed up for a free trial at Espresso Logic, to try Live Browser myself. I could log into Logic Designer immediately (as described in my previous article). Do note that there is no single-sign-on in place between the Logic Designer and the Live Browser, so I needed to reuse my credentials to log in also to the browser.

Once I’ve logged in, I could really play around with the data in an easy and straightforward way. All the server-side rules that calculate totals are working as well. E.g. I tried changing the price for a product inside a PurchaseOrder (i.e. inside a LineItem), and it updated the PurchaseOrder’s “Amount Total” value automatically.

I wish I had created this product three years ago when SaaS started getting big. Now, I guess, it’s too late… Congrats, Espresso Logic!

More information

For more info, read Val’s article on DZone

Yet Another 10 Common Mistakes Java Developers Make When Writing SQL (You Won’t BELIEVE the Last One)


(Sorry for that click-bait heading. Couldn’t resist 😉 )

We’re on a mission. To teach you SQL. But mostly, we want to teach you how to appreciate SQL. You’ll love it!

Getting SQL right or wrong shouldn’t be about that You’re-Doing-It-Wrong™ attitude that can be encountered often when evangelists promote their object of evangelism. Getting SQL right should be about the fun you’ll have once you do get it right. The things you start appreciating when you notice that you can easily replace 2000 lines of slow, hard-to-maintain, and ugly imperative (or object-oriented) code with 300 lines of lean functional code (e.g. using Java 8), or even better, with 50 lines of SQL.

We’re glad to see that our blogging friends have started appreciating SQL, and most specifically, window functions after reading our posts. For instance, take

So, after our previous, very popular posts:

… we’ll bring you:

Yet Another 10 Common Mistakes Java Developer Make When Writing SQL

And of course, this doesn’t apply to Java developers alone, but it’s written from the perspective of a Java (and SQL) developer. So here we go (again):

1. Not Using Window Functions

After all that we’ve been preaching, this must be our number 1 mistake in this series. Window functions are probably the coolest SQL feature of them all. They’re so incredibly useful, they should be the number one reason for anyone to switch to a better database, e.g. PostgreSQL:

If free and/or Open Source is important to you, you have absolutely no better choice than using PostgreSQL (and you’ll even get to use the free jOOQ Open Source Edition, if you’re a Java developer).

And if you’re lucky enough to work in an environment with Oracle or SQL Server (or DB2, Sybase) licenses, you get even more out of your new favourite tool.

We won’t repeat all the window function goodness in this section, we’ve blogged about them often enough:

The Cure:

Remove MySQL. Take a decent database. And start playing with window functions. You’ll never go back, guaranteed.

2. Not declaring NOT NULL constraints

This one was already part of a previous list where we claimed that you should add as much metadata as possible to your schema, because your database will be able to leverage that metadata for optimisations. For instance, if your database knows that a foreign key value in BOOK.AUTHOR_ID must also be contained exactly once in AUTHOR.ID, then a whole set of optimisations can be achieved in complex queries.

Now let’s have another look at NOT NULL constraints. If you’re using Oracle, NULL values will not be part of your index. This doesn’t matter if you’re expressing an IN constraint, for instance:

SELECT * FROM table
WHERE value IN (
  SELECT nullable_column FROM ...
)

But what happens with a NOT IN constraint?

SELECT * FROM table
WHERE value NOT IN (
  SELECT nullable_column FROM ...
)

Due to SQL’s slightly unintuitive way of handling NULL, there is a slight risk of the second query unexpectedly not returning any results at all, namely if there is at least one NULL value as a result from the subquery. This is true for all databases that get SQL right.

But because the index on nullable_column doesn’t contain any NULL values, Oracle has to look up the complete content in the table, resulting in a FULL TABLE SCAN. Now that is unexpected! Details about this can be seen in this article.

The Cure:

Carefully review all your nullable, yet indexed columns, and check if you really cannot add a NOT NULL constraint to those columns.

The Tool:

If you’re using Oracle, use this query to detect all nullable, yet indexed columns:

SELECT
  i.table_name,
  i.index_name,
  LISTAGG(
    LPAD(i.column_position,  2) || ': ' || 
    RPAD(i.column_name    , 30) || ' '  ||
    DECODE(t.nullable, 'Y', '(NULL)', '(NOT NULL)'), 
    ', '
  ) WITHIN GROUP (ORDER BY i.column_position) 
    AS "NULLABLE columns in indexes"
FROM user_ind_columns i
JOIN user_tab_cols t
ON (t.table_name, t.column_name) = 
  ((i.table_name, i.column_name))
WHERE EXISTS (
  SELECT 1
  FROM user_tab_cols t
  WHERE (t.table_name, t.column_name, t.nullable) = 
       ((i.table_name, i.column_name, 'Y'       ))
)
GROUP BY i.table_name, i.index_name
ORDER BY i.index_name ASC;

Example output:

TABLE_NAME | INDEX_NAME   | NULLABLE columns in indexes
-----------+--------------+----------------------------
PERSON     | I_PERSON_DOB | 1: DATE_OF_BIRTH (NULL)

And then, fix it!

(Accidental criticism of Maven is irrelevant here 😉 )

If you’re curious about more details, see also these posts:

3. Using PL/SQL Package State

Now, this is a boring one if you’re not using Oracle, but if you are (and you’re a Java developer), be very wary of PL/SQL package state. Are you really doing what you think you’re doing?

Yes, PL/SQL has package-state, e.g.

CREATE OR REPLACE PACKAGE pkg IS
  -- Package state here!
  n NUMBER := 1;

  FUNCTION next_n RETURN NUMBER;
END pkg;

CREATE OR REPLACE PACKAGE BODY pkg IS
  FUNCTION next_n RETURN NUMBER
  IS
  BEGIN
    n := n + 1;
    RETURN n;
  END next_n;
END pkg;

Wonderful, so you’ve created yourself an in-memory counter that generates a new number every time you call pkg.next_n. But who owns that counter? Yes, the session. Each session has their own initialised “package instance”.

But no, it’s probably not the session you might have thought of.

We Java developers connect to databases through connection pools. When we obtain a JDBC Connection from such a pool, we recycle that connection from a previous “session”, e.g. a previous HTTP Request (not HTTP Session!). But that’s not the same. The database session (probably) outlives the HTTP Request and will be inherited by the next request, possibly from an entirely different user. Now, imagine you had a credit card number in that package…?

Not The Cure:

Nope. Don’t just jump to using SERIALLY_REUSABLE packages

CREATE OR REPLACE PACKAGE pkg IS
  PRAGMA SERIALLY_REUSABLE;
  n NUMBER := 1;

  FUNCTION next_n RETURN NUMBER;
END pkg;

Because:

  • You cannot even use that package from SQL, now (see ORA-06534).
  • Mixing this PRAGMA with regular package state from other packages just makes things a lot more complex.

So, don’t.

Not The Cure:

I know. PL/SQL can be a beast. It often seems like such a quirky language. But face it. Many things run much much faster when written in PL/SQL, so don’t give up, just yet. Dropping PL/SQL is not the solution either.

The Cure:

At all costs, try to avoid package state in PL/SQL. Think of package state as of static variables in Java. While they might be useful for caches (and constants, of course) every now and then, you might not actually access that state that you wanted. Think about load-balancers, suddenly transferring you to another JVM. Think about class loaders, that might have loaded the same class twice, for some reason.

Instead, pass state as arguments through procedures and functions. This will avoid side-effects and make your code much cleaner and more predictable.

Or, obviuously, persist state to some table.

4. Running the same query all the time

Master data is boring. You probably wrote some utility to get the latest version of your master data (e.g. language, locale, translations, tenant, system settings), and you can query it every time, once it is available.

At all costs, don’t do that. You don’t have to cache many things in your application, as modern databases have grown to be extremely fast when it comes to caching:

  • Table / column content
  • Index content
  • Query / materialized view results
  • Procedure results (if they’re deterministic)
  • Cursors
  • Execution plans

So, for your average query, there’s virtually no need for an ORM second-level cache, at least from a performance perspective (ORM caches mainly fulfil other purposes, of course).

But when you query master data, i.e. data that never changes, then, network latency, traffic and many other factors will impair your database experience.

The Cure:

Please do take 10 minutes, download Guava, and use its excellent and easy to set up cache, that ships with various built-in invalidation strategies. Choose time-based invalidation (i.e. polling), choose Oracle AQ or Streams, or PostgreSQL’s NOTIFY for event-based invalidation, or just make your cache permanent, if it doesn’t matter. But don’t issue an identical master data query all the time.

… This obviously brings us to

5. Not knowing about the N+1 problem

You had a choice. At the beginning of your software product, you had to choose between:

So, obviously, you chose an ORM, because otherwise you wouldn’t be suffering from “N+1”. What does “N+1” mean?

The accepted answer on this Stack Overflow question explains it nicely. Essentially, you’re running:

SELECT * FROM book

-- And then, for each book:
SELECT * FROM author WHERE id = ?
SELECT * FROM author WHERE id = ?
SELECT * FROM author WHERE id = ?

Of course, you could go and tweak your hundreds of annotations to correctly prefetch or eager fetch each book’s associated author information to produce something along the lines of:

SELECT * 
FROM   book
JOIN   author 
  ON   book.author_id = author.id

But that would be an awful lot of work, and you’ll risk eager-fetching too many things that you didn’t want, resulting in another performance issue.

Maybe, you could upgrade to JPA 2.1 and use the new @NamedEntityGraph to express beautiful annotation trees like this one:

@NamedEntityGraph(
    name = "post",
    attributeNodes = {
        @NamedAttributeNode("title"),
        @NamedAttributeNode(
            value = "comments", 
            subgraph = "comments"
        )
    },
    subgraphs = {
        @NamedSubgraph(
            name = "comments",
            attributeNodes = {
                @NamedAttributeNode("content")
            }
        )
    }
)

The example was taken from this blog post by Hantsy Bai. Hantsy then goes on explaining that you can use the above beauty through the following statement:

em.createQuery("select p from Post p where p.id=:id",
               Post.class)
  .setHint("javax.persistence.fetchgraph", 
           postGraph)
  .setParameter("id", this.id)
  .getResultList()
  .get(0);

Let us all appreciate the above application of JEE standards with all due respect, and then consider…

The Cure:

You just listen to the wise words at the beginning of this article and replace thousands of lines of tedious Java / Annotatiomania™ code with a couple of lines of SQL. Because that will also likely help you prevent another issue that we haven’t even touched yet, namely selecting too many columns as you can see in these posts:

Since you’re already using an ORM, this might just mean resorting to native SQL – or maybe you manage to express your query with JPQL. Of course, we agree with Alessio Harri in believing that you should use jOOQ together with JPA:

The Takeaway:

While the above will certainly help you work around some real world issues that you may have with your favourite ORM, you could also take it one step further and think about it this way. After all these years of pain and suffering from the object-relational impedance mismatch, the JPA 2.1 expert group is now trying to tweak their way out of this annotation madness by adding more declarative, annotation-based fetch graph hints to JPQL queries, that no one can debug, let alone maintain.

The alternative is simple and straight-forward SQL. And with Java 8, we’ll add functional transformation through the Streams API. That’s hard to beat.

But obviuosly, your views and experiences on that subject may differ from ours, so let’s head on to a more objective discussion about…

6. Not using Common Table Expressions

While common table expressions obviously offer readability improvements, they may also offer performance improvements. Consider the following query that I have recently encountered in a customer’s PL/SQL package (not the actual query):

SELECT round (
  (SELECT amount FROM payments WHERE id = :p_id)
    * 
  (
    SELECT e.bid
    FROM   currencies c, exchange_rates e
    WHERE  c.id     = 
      (SELECT cur_id FROM payments WHERE id = :p_id)
    AND    e.cur_id = 
      (SELECT cur_id FROM payments WHERE id = :p_id)
    AND    e.org_id = 
      (SELECT org_id FROM payments WHERE id = :p_id)
  ) / (
    SELECT c.factor
    FROM   currencies c, exchange_rates e
    WHERE  c.id     = 
      (SELECT cur_id FROM payments WHERE id = :p_id)
    AND    e.cur_id = 
      (SELECT cur_id FROM payments WHERE id = :p_id)
    AND    e.org_id = 
      (SELECT org_id FROM payments WHERE id = :p_id)
  ), 0
) 
INTO amount 
FROM dual;

So what does this do? This essentially converts a payment’s amount from one currency into another. Let’s not delve into the business logic too much, let’s head straight to the technical problem. The above query results in the following execution plan (on Oracle):

------------------------------------------------------
| Operation                         | Name           |
------------------------------------------------------
| SELECT STATEMENT                  |                |
|  TABLE ACCESS BY INDEX ROWID      | PAYMENTS       |
|   INDEX UNIQUE SCAN               | PAYM_PK        |
|   NESTED LOOPS                    |                |
|    INDEX UNIQUE SCAN              | CURR_PK        |
|     TABLE ACCESS BY INDEX ROWID   | PAYMENTS       |
|      INDEX UNIQUE SCAN            | PAYM_PK        |
|    TABLE ACCESS BY INDEX ROWID    | EXCHANGE_RATES |
|     INDEX UNIQUE SCAN             | EXCH_PK        |
|      TABLE ACCESS BY INDEX ROWID  | PAYMENTS       |
|       INDEX UNIQUE SCAN           | PAYM_PK        |
|      TABLE ACCESS BY INDEX ROWID  | PAYMENTS       |
|       INDEX UNIQUE SCAN           | PAYM_PK        |
|     NESTED LOOPS                  |                |
|      TABLE ACCESS BY INDEX ROWID  | CURRENCIES     |
|       INDEX UNIQUE SCAN           | CURR_PK        |
|        TABLE ACCESS BY INDEX ROWID| PAYMENTS       |
|         INDEX UNIQUE SCAN         | PAYM_PK        |
|      INDEX UNIQUE SCAN            | EXCH_PK        |
|       TABLE ACCESS BY INDEX ROWID | PAYMENTS       |
|        INDEX UNIQUE SCAN          | PAYM_PK        |
|       TABLE ACCESS BY INDEX ROWID | PAYMENTS       |
|        INDEX UNIQUE SCAN          | PAYM_PK        |
|  FAST DUAL                        |                |
------------------------------------------------------

The actual execution time is negligible in this case, but as you can see, the same objects are accessed again and again within the query. This is a violation of Common Mistake #4: Running the same query all the time.

The whole thing would be so much easier to read, maintain, and for Oracle to execute, if we had used a common table expression. From the original source code, observe the following thing:

-- We're always accessing a single payment:
  FROM payments WHERE id = :p_id

-- Joining currencies and exchange_rates twice:
  FROM currencies c, exchange_rates e

So, let’s factor out the payment first:

-- "payment" contains only a single payment
-- But it contains all the columns that we'll need
-- afterwards
WITH payment AS (
    SELECT cur_id, org_id, amount
    FROM   payments
    WHERE  id = :p_id
)
SELECT round(p.amount * e.bid / c.factor, 0)

-- Then, we simply don't need to repeat the
-- currencies / exchange_rates joins twice
FROM   payment p
JOIN   currencies c     ON  p.cur_id = c.id
JOIN   exchange_rates e ON  e.cur_id = p.cur_id
                        AND e.org_id = p.org_id

Note, that we’ve also replaced table lists with ANSI JOINs as suggested in our previous list

You wouldn’t believe it’s the same query, would you? And what about the execution plan? Here it is!

---------------------------------------------------
| Operation                      | Name           |
---------------------------------------------------
| SELECT STATEMENT               |                |
|  NESTED LOOPS                  |                |
|   NESTED LOOPS                 |                |
|    NESTED LOOPS                |                |
|     FAST DUAL                  |                |
|     TABLE ACCESS BY INDEX ROWID| PAYMENTS       |
|      INDEX UNIQUE SCAN         | PAYM_PK        |
|    TABLE ACCESS BY INDEX ROWID | EXCHANGE_RATES |
|     INDEX UNIQUE SCAN          | EXCH_PK        |
|   TABLE ACCESS BY INDEX ROWID  | CURRENCIES     |
|    INDEX UNIQUE SCAN           | CURR_PK        |
---------------------------------------------------

No doubt that this is much much better.

The Cure:

If you’re lucky enough and you’re using one of those databases that supports window functions, chances are incredibly high (100%) that you also have common table expression support. This is another reason for you to migrate from MySQL to PostgreSQL, or appreciate the fact that you can work on an awesome commercial database.

Common table expressions are like local variables in SQL. In every large statement, you should consider using them, as soon as you feel that you’ve written something before.

The Takeaway:

Some databases (e.g. PostgreSQL, or SQL Server) also support common table expressions for DML statements. In other words, you can write:

WITH ...
UPDATE ...

This makes DML incredibly more powerful.

7. Not using row value expressions for UPDATEs

We’ve advertised the use of row value expressions in our previous listing. They’re very readable and intuitive, and often also promote using certain indexes, e.g. in PostgreSQL.

But few people know that they can also be used in an UPDATE statement, in most databases. Check out the following query, which I again found in a customer’s PL/SQL package (simplified again, of course):

UPDATE u
SET n = (SELECT n + 1    FROM t WHERE u.n = t.n),
    s = (SELECT 'x' || s FROM t WHERE u.n = t.n),
    x = 3;

So this query takes a subquery as a data source for updating two columns, and the third column is updated “regularly”. How does it perform? Moderately:

-----------------------------
| Operation          | Name |
-----------------------------
| UPDATE STATEMENT   |      |
|  UPDATE            | U    |
|   TABLE ACCESS FULL| U    |
|   TABLE ACCESS FULL| T    |
|   TABLE ACCESS FULL| T    |
-----------------------------

Let’s ignore the full table scans, as this query is constructed. The actual query could leverage indexes. But T is accessed twice, i.e. in both subqueries. Oracle didn’t seem to be able to apply scalar subquery caching in this case.

To the rescue: row value expressions. Let’s simply rephrase our UPDATE to this:

UPDATE u
SET (n, s) = ((
      SELECT n + 1, 'x' || s FROM t WHERE u.n = t.n
    )),
    x = 3;

Let’s ignore the funny, Oracle-specific double-parentheses syntax for the right hand side of such a row value expression assignment, but let’s appreciate the fact that we can easily assign a new value to the tuple (n, s) in one go! Note, we could have also written this, instead, and assign x as well:

UPDATE u
SET (n, s, x) = ((
      SELECT n + 1, 'x' || s, 3 
      FROM t WHERE u.n = t.n
    ));

As you will have expected, the execution plan has also improved, and T is accessed only once:

-----------------------------
| Operation          | Name |
-----------------------------
| UPDATE STATEMENT   |      |
|  UPDATE            | U    |
|   TABLE ACCESS FULL| U    |
|   TABLE ACCESS FULL| T    |
-----------------------------

The Cure:

Use row value expressions. Where ever you can. They make your SQL code incredibly more expressive, and chances are, they make it faster, as well.

Note that the above is supported by jOOQ’s UPDATE statement. This is the moment we would like to make you aware of this cheap, in-article advertisement:

jOOQ - The best way to write SQL in Java

😉

8. Using MySQL when you could use PostgreSQL

To some, this may appear to be a bit of a hipster discussion. But let’s consider the facts:

  • MySQL claims to be the “most popular Open Source database”.
  • PostgreSQL claims to be the “most advanced Open Source database”.

Let’s consider a bit of history. MySQL has always been very easy to install, maintain, and it has had a great and active community. This has lead to MySQL still being the RDBMS of choice with virtually every web hoster on this planet. Those hosters also host PHP, which was equally easy to install, and maintain.

BUT!

We Java developers tend to have an opinion about PHP, right? It’s summarised by this image here:

The PHP Hammer

The PHP Hammer

Well, it works, but how does it work?

The same can be said about MySQL. MySQL has always worked somehow, but while commercial databases like Oracle have made tremendous progress both in terms of query optimisation and feature scope, MySQL has hardly moved in the last decade.

Many people choose MySQL primarily because of its price (USD $ 0.00). But often, the same people have found MySQL to be slow and quickly concluded that SQL is slow per se – without evaluating the options. This is also why all NoSQL stores compare themselves with MySQL, not with Oracle, the database that has been winning the Transaction Processing Performance Council’s (TPC) benchmarks almost forever. Some examples:

While the last article bluntly adds “(and other RDBMS)” it doesn’t go into any sort of detail whatsoever, what those “other RDBMS” do wrong. It really only compares MongoDB with MySQL.

The Cure:

We say: Stop complaining about SQL, when in fact, you’re really complaining about MySQL. There are at least four very popular databases out there that are incredibly good, and millions of times better than MySQL. These are:

(just kidding about the last one, of course)

The Takeaway:

Don’t fall for agressive NoSQL marketing. 10gen is an extremely well-funded company, even if MongoDB continues to disappoint, technically.

The same is true for Datastax.

Both companies are solving a problem that few people have. They’re selling us niche products as commodity, making us think that our real commodity databases (the RDBMS) no longer fulfil our needs. They are well-funded and have big marketing teams to throw around with blunt claims.

In the mean time, PostgreSQL just got even better, and you, as a reader of this blog / post, are about to bet on the winning team 🙂

… just to cite Mark Madsen once more:

The Disclaimer:

This article has been quite strongly against MySQL. We don’t mean to talk badly about a database that perfectly fulfils its purpose, as this isn’t a black and white world. Heck, you can get happy with SQLite in some situations. MySQL, being the cheap and easy to use, easy to install commodity database. We just wanted to make you aware of the fact, that you’re expressly choosing the cheap, not-so-good database, rather than the cheap, awesome one.

9. Forgetting about UNDO / REDO logs

We have claimed that MERGE statements or bulk / batch updates are good. That’s correct, but nonetheless, you should be wary when updating huge data sets in transactional contexts. If your transaction “takes too long”, i.e. if you’re updating 10 million records at a time, you will run into two problems:

  • You increase the risk of race conditions, if another process is also writing to the same table. This may cause a rollback on their or on your transaction, possibly making you roll out the huge update again
  • You cause a lot of concurrency on your system, because every other transaction / session, that wants to see the data that you’re about to update, will have to temporarily roll back all of your updates first, before they reach the state on disk that was there before your huge update. That’s the price of ACID.

One way to work around this issue is to allow for other sessions to read uncommitted data.

Another way to work around this issue is to frequently commit your own work, e.g. after 1000 inserts / updates.

In any case, due to the CAP theorem, you will have to make a compromise. Frequent commits will produce the risk of an inconsistent database in the event of the multi-million update going wrong after 5 million (committed) records. A rollback would then mean to revert all database changes towards a backup.

The Cure:

There is no definitive cure to this issue. But beware that you are very very rarely in a situation where it is OK to simply update 10 million records of a live and online table outside of an actual scheduled maintenance window. The simplest acceptable workaround is indeed to commit your work after N inserts / updates.

The Takeaway:

By this time, NoSQL aficionados will claim (again due to excessive marketing by aforementioned companies) that NoSQL has solved this by dropping schemas and typesafety. “Don’t update, just add another property!” – they said.

But that’s not true!

First off, I can add columns to my database without any issue at all. An ALTER TABLE ADD statement is executed instantly on live databases. Filling the column with data doesn’t bother anyone either, because no one reads the column yet (remember, don’t SELECT * !). So adding columns in RDBMS is as cheap as adding JSON properties to a MongoDB document.

But what about altering columns? Removing them? Merging them?

It is simply not true that denormalisation takes you anywhere far. Denormalisation is always a short-term win for the developer. Hardly a long-term win for the operations teams. Having redundant data in your database for the sake of speeding up an ALTER TABLE statement is like sweeping dirt under the carpet.

Don’t believe the marketers. And while you’re at it, perform some doublethink and forget that we’re SQL tool vendors ourselves 😉 Here’s again the “correct” message:

jOOQ - The best way to write SQL in Java

10. Not using the BOOLEAN type correctly

This is not really a mistake per se. It’s just again something that hardly anyone knows. When the SQL:1999 standard introduced the new BOOLEAN data type, they really did it right. Because before, we already had something like booleans in SQL. We’ve had <search condition> in SQL-92, which are essentially predicates for use in WHERE, ON, and HAVING clauses, as well as in CASE expressions.

SQL:1999, however, simply defined the new <boolean value expression> as a regular <value expression>, and redefined the <search condition> as such:

<search condition> ::=
    <boolean value expression>

Done! Now, for most of us Java / Scala / etc. developers, this doesn’t seem like such an innovation. Heck it’s a boolean. Obviuosly it can be interchangeably used as predicate and as variable.

But in the mind-set of the keyword-heavy SQL folks who have taken inspiration from COBOL when designing the language, this was quite a step forward.

Now, what does this mean? This means that you can use any predicate also as a column! For instance:

SELECT a, b, c
FROM (
  SELECT EXISTS (SELECT ...) a,
         MY_COL IN (1, 2, 3) b,
         3 BETWEEN 4 AND 5   c
  FROM   MY_TABLE
) t
WHERE a AND b AND NOT(c)

This is a bit of a dummy query, agreed, but are you aware of how powerful this is?

Luckily, again, PostgreSQL fully supports this (unlike Oracle, which still doesn’t have any BOOLEAN data type in SQL).

The Cure:

Every now and then, using BOOLEAN types feels very right, so do it! You can transform boolean value expressions into predicates and predicates into boolean value expressions. They’re the same. This makes SQL all so powerful.

Conclusion

SQL has evolved steadily over the past years through great standards like SQL:1999, SQL:2003, SQL:2008 and now SQL:2011. It is the only surviving mainstream declarative language, now that XQuery can be considered pretty dead for the mainstream. It can be easily mixed with procedural languages, as PL/SQL and T-SQL (and other procedural dialects) have shown. It can be easily mixed with object-oriented or functional languages, as jOOQ has shown.

At Data Geekery, we believe that SQL is the best way to query data. You don’t agree with any of the above? That’s fine, you don’t have to. Sometimes, even we agree with Winston Churchill who is known to have said:

tweet thisSQL is the worst form of database querying, except for all the other forms.

But as Yakov Fain has recently put it:

You can run from SQL, but you can’t hide

So, let’s better get back to work and learn this beast! Thanks for reading.

Java 8 Friday: Better Exceptions


At Data Geekery, we love Java. And as we’re really into jOOQ’s fluent API and query DSL, we’re absolutely thrilled about what Java 8 will bring to our ecosystem.

Java 8 Friday

Every Friday, we’re showing you a couple of nice new tutorial-style Java 8 features, which take advantage of lambda expressions, extension methods, and other great stuff. You’ll find the source code on GitHub.

Better Exceptions

I had the idea when I stumbled upon JUnit GitHub issue #706, which is about a new method proposal:

ExpectedException#expect(Throwable, Callable)

One suggestion was to create an interceptor for exceptions like this.

assertEquals(Exception.class, 
    thrown(() -> foo()).getClass());
assertEquals("yikes!", 
    thrown(() -> foo()).getMessage());

On the other hand, why not just add something completely new along the lines of this?

// This is needed to allow for throwing Throwables
// from lambda expressions
@FunctionalInterface
interface ThrowableRunnable {
    void run() throws Throwable;
}

// Assert a Throwable type
static void assertThrows(
    Class<? extends Throwable> throwable,
    ThrowableRunnable runnable
) {
    assertThrows(throwable, runnable, t -> {});
}

// Assert a Throwable type and implement more
// assertions in a consumer
static void assertThrows(
    Class<? extends Throwable> throwable,
    ThrowableRunnable runnable,
    Consumer<Throwable> exceptionConsumer
) {
    boolean fail = false;
    try {
        runnable.run();
        fail = true;
    }
    catch (Throwable t) {
        if (!throwable.isInstance(t))
            Assert.fail("Bad exception type");

        exceptionConsumer.accept(t);
    }

    if (fail)
        Assert.fail("No exception was thrown");
}

So the above methods both assert that a given throwable is thrown from a given runnable – ThrowableRunnable to be precise, because most functional interfaces, unfortunately, don’t allow for throwing checked exceptions. See this article for details.

We’re now using the above hypothetical JUnit API as such:

assertThrows(Exception.class, 
    () -> { throw new Exception(); });

assertThrows(Exception.class, 
    () -> { throw new Exception("Message"); },
    e  -> assertEquals("Message", e.getMessage()));

In fact, we could even go further and declare an exception swallowing helper method like this:

// This essentially swallows exceptions
static void withExceptions(
    ThrowableRunnable runnable
) {
    withExceptions(runnable, t -> {});
}

// This delegates exception handling to a consumer
static void withExceptions(
    ThrowableRunnable runnable,
    Consumer<Throwable> exceptionConsumer
) {
    try {
        runnable.run();
    }
    catch (Throwable t) {
        exceptionConsumer.accept(t);
    }
}

This is useful to swallow all sorts of exceptions. The following two idioms are thus equivalent:

try {
    // This will fail
    assertThrows(SQLException.class, () -> {
        throw new Exception();
    });
}
catch (Throwable t) {
    t.printStackTrace();
}

withExceptions(
    // This will fail
    () -> assertThrows(SQLException.class, () -> {
        throw new Exception();
    }),
    t -> t.printStackTrace()
);

Obviuously, these idioms aren’t necessarily more useful than an actual try .. catch .. finally block, specifically also because it does not support proper typing of exceptions (at least not in this example), nor does it support the try-with-resources statement.

Nonetheless, such utility methods will come in handy every now and then.

Next week

Stay tuned for more Java 8 goodness on this blog when we continue our Java 8 Friday series with great new examples.

Oracle Tip: v$sql Table or View does not Exist


If we want to analyse execution plans on the SQL console, we probably need to find a SQL_ID first, which we can the pass to the DBMS_XPLAN.DISPLAY_CURSOR function. One way to find this SQL_ID is by querying the v$sql table first, e.g.:

SELECT   last_active_time, 
         sql_id, 
         child_number, 
         sql_text
FROM     v$sql
WHERE    upper(sql_fulltext) LIKE '%SOME_SQL_TEXT%'
ORDER BY last_active_time DESC;

Now, often, you will then get an error message like:

ORA-00942: table or view does not exist

This simply means that you do not have the required privileges to select from that table. Have your DBA give you the required grant, or do it yourself on your local Oracle instance with:

C:\> sqlplus "/ as sysdba"

SQL> GRANT SELECT ANY DICTIONARY TO MY_USER;

Grant succeeded

Done. You can now query v$sql

More details about how to analyse execution plans on the SQL console can be seen here.

jOOQ Newsletter: May 21, 2014 – jOOQ Community Video Tutorials


Subscribe to this newsletter here

Tweet of the Day

Our customers, users, and followers are sharing their love for jOOQ with the world. Here are:

Chris Martin who has switched jobs and is now really missing jOOQ. Too bad we can’t offer jOOQ for Python, Chris!

Moutaz Salem who had been waiting for jOOQ for all these years. But we’re here now, Moutaz. The pain has ended!

Simon Martinelli who is contemplating migration to jOOQ from Hibernate. Go for it Simon!

Thanks for the shouts, guys! You make the jOOQ experience rock!

Closing in on jOOQ 3.4

We’re almost there! In early June, we’ll ship the awesome jOOQ 3.4 – a very ambitious project in which we’re finally going to tackle a couple of very important missing features. The ones that have made it through our roadmap optimisations are:

  • Support for type safe DDL statements.
  • Support for common table expressions.
  • A unified SQL transformation API.

SQL transformation can be very effective for dialect standardisation, multi-tenancy, soft-deleting, row-level security and many more features. Have you used it yet? You should!

Better SQL transformation APIs will make your VisitListeners even more powerful, and custom QueryParts even easier to implement. If you’re a hard-core SQL transformation aficionado, this is great news for you as you can exert even more control over jOOQ’s SQL rendering.

In an earlier newsletter, we had promised to implement Informix support, but we had to optimise our roadmap to ensure the above gets shipped with the usual quality that we’re offering to our customers. We’re very sorry if that has affected you. We’ll try to have this in jOOQ 3.5, though.

Of course, there are lots of other minor improvements, so stay tuned for the release, very soon

Community Zone – The jOOQ aficionados have been active!

In previous newsletters, we’ve advertised jOOQ community blog post contributions, which are a really awesome way to show your love – thank you very much, again!

In the previous weeks, however, we’ve discovered these two video contributions:

A jOOQ video tutorial by Ruben Alexander More Valencia (Spanish)

A jOOQ and Flyway presentation by Dmitry Lebedev and Rustam Arslanov (Latvian)

This is really great, thank you so much, guys! If you want to present jOOQ to your local JUG, do so today! If you need any brand material, example slides, example projects, or other material, please do contact us. We’re more than happy to provide you with what you need.

SQL Zone – Sort indirection

Every now and then, you may want to sort your records in a bit of a “quirky” way, i.e. by explicitly putting 1-2 values at the top and all the other values below. We refer to this as “sort indirection”, which can be achieved with a clever ORDER BY clause along with a CASE expression:

ORDER BY
  CASE WHEN name = 'val1' THEN 1
       WHEN name = 'val2' THEN 2
       WHEN name = 'val3' THEN 3
       WHEN name = 'val4' THEN 4
  END

Of course, jOOQ natively implements a couple of convenience methods to achieve the same.

Read the full article here:
https://blog.jooq.org/2014/05/07/how-to-implement-sort-indirection-in-sql/

SQL Zone – Identifier madness

We’ve said it before. We’ll say it again.

You should NEVER rely on case-sensitivity (or case-insensitivity) when writing vendor-agnostic SQL. It is hard enough to remember the rules in one single database, but if you ship your software to support various RDBMS, always force your identifiers to be case-sensitive (and settle for either all-uppercase or all-lowercase).

Fortunately, jOOQ takes care of case-sensitivity by default, quoting all your identifier as they were reported from the database.

You want to know why this is important? Consider reading this article where the various caveats and differences between identifier parts are explained and compared between databases:
http://wiki.ispirer.com/sqlways/sybase/identifiers

Upcoming Events

GeeCON in Kraków is already over. Great conference and many great speakers!

As always in recent conferences, topics mainly included JavaScript, Akka, Node.js and Vert.x and other hip subjects. But we’re always amazed to see how big of a crowd can still be motivated into a “plain old SQL” talk like ours. SQL (and the latest standards) is still very awesome, and every time we explain the merits of window functions, we see hundreds of wide-open eyes, with awe and revelation.

😉

Have you missed any of our previous jOOQ talks? Soon you’ll get another chance to hear us talk about jOOQ or SQL in general in any of these upcoming events:

Stay informed about 2014 events on www.jooq.org/news.