Saturday, March 10, 2012

SQLite, JPA (Hibernate implementation) and Pagination

I was having issues with a Wicket AjaxFallbackDefaultDataTable, where I couldn't get the pagination working properly with an SQLite database.

The relevant code I was using for pagination was this:

 String query = "SELECT p FROM Person p ORDER BY p." 
          + getSort().getProperty() 
          " " 
          + ascDesc;
TypedQuery personQuery= em.createQuery(query, Person.class);
personQuery.setFirstResult(first);  // first is passed in by the datatable
personQuery.setMaxResults(count);   // count is passed in by the datatable


It turned out that the problem was with the SQLite dialect I was using.

Using Log4JDBC I was able to view the values in the LIMIT and OFFSET clauses in the SQL statements that JPA was creating and executing.  So instead of seeing this:

LIMIT ? OFFSET ?

I could now see this:

LIMIT 10 OFFSET 0

When setting the firstResult to 10 personQuery.setFirstResult(10) and setMaxResults to 6 personQuery.setMaxResults(6) I noticed that the SQL statement was reversing the arguments to the LIMIT and OFFSET clauses, so instead of getting what I was expecting LIMIT 6 OFFSET 10 I was getting LIMIT 10 OFFSET 6

The solution was to override the bindLimitParametersInReverseOrder() method and set it to return true and that allowed my pagination to start working as expected.
Note: You can't change the getLimitString method to return LIMIT and OFFSET in reverse order. That causes a syntax error.

Here's the slightly modified SQLite dialect (I found the original on the net) that will work with pagination.


import java.sql.Types;

import org.hibernate.dialect.Dialect;
import org.hibernate.dialect.function.StandardSQLFunction;
import org.hibernate.dialect.function.SQLFunctionTemplate;
import org.hibernate.dialect.function.VarArgsSQLFunction;
import org.hibernate.Hibernate;

public class SQLiteDialect extends Dialect {
  public SQLiteDialect() {
    super();
    registerColumnType(Types.BIT, "integer");
    registerColumnType(Types.TINYINT, "tinyint");
    registerColumnType(Types.SMALLINT, "smallint");
    registerColumnType(Types.INTEGER, "integer");
    registerColumnType(Types.BIGINT, "bigint");
    registerColumnType(Types.FLOAT, "float");
    registerColumnType(Types.REAL, "real");
    registerColumnType(Types.DOUBLE, "double");
    registerColumnType(Types.NUMERIC, "numeric");
    registerColumnType(Types.DECIMAL, "decimal");
    registerColumnType(Types.CHAR, "char");
    registerColumnType(Types.VARCHAR, "varchar");
    registerColumnType(Types.LONGVARCHAR, "longvarchar");
    registerColumnType(Types.DATE, "date");
    registerColumnType(Types.TIME, "time");
    registerColumnType(Types.TIMESTAMP, "timestamp");
    registerColumnType(Types.BINARY, "blob");
    registerColumnType(Types.VARBINARY, "blob");
    registerColumnType(Types.LONGVARBINARY, "blob");
    // registerColumnType(Types.NULL, "null");
    registerColumnType(Types.BLOB, "blob");
    registerColumnType(Types.CLOB, "clob");
    registerColumnType(Types.BOOLEAN, "integer");

    registerFunction("concat"new VarArgsSQLFunction(Hibernate.STRING, "",
        "||"""));
    registerFunction("mod"new SQLFunctionTemplate(Hibernate.INTEGER,
        "?1 % ?2"));
    registerFunction("substr"new StandardSQLFunction("substr",
        Hibernate.STRING));
    registerFunction("substring"new StandardSQLFunction("substr",
        Hibernate.STRING));
  }

  public boolean supportsIdentityColumns() {
    return true;
  }

  public boolean hasDataTypeInIdentityColumn() {
    return false// As specify in NHibernate dialect
  }

  public String getIdentityColumnString() {
    // return "integer primary key autoincrement";
    return "integer";
  }

  public String getIdentitySelectString() {
    return "select last_insert_rowid()";
  }

  public boolean supportsLimit() {
    return true;
  }

  public String getLimitString(String query, boolean hasOffset) {
    return new StringBuffer(query.length() 20).append(query).append(
        hasOffset ? " limit ? offset ?" " limit ?").toString();
  }
  
  public boolean bindLimitParametersInReverseOrder() {
    return true;
  }

  public boolean supportsTemporaryTables() {
    return true;
  }

  public String getCreateTemporaryTableString() {
    return "create temporary table if not exists";
  }

  public boolean dropTemporaryTableAfterUse() {
    return false;
  }

  public boolean supportsCurrentTimestampSelection() {
    return true;
  }

  public boolean isCurrentTimestampSelectStringCallable() {
    return false;
  }

  public String getCurrentTimestampSelectString() {
    return "select current_timestamp";
  }

  public boolean supportsUnionAll() {
    return true;
  }

  public boolean hasAlterTable() {
    return false// As specify in NHibernate dialect
  }

  public boolean dropConstraints() {
    return false;
  }

  public String getAddColumnString() {
    return "add column";
  }

  public String getForUpdateString() {
    return "";
  }

  public boolean supportsOuterJoinForUpdate() {
    return false;
  }

  public String getDropForeignKeyString() {
    throw new UnsupportedOperationException(
        "No drop foreign key syntax supported by SQLiteDialect");
  }

  public String getAddForeignKeyConstraintString(String constraintName,
      String[] foreignKey, String referencedTable, String[] primaryKey,
      boolean referencesPrimaryKey) {
    throw new UnsupportedOperationException(
        "No add foreign key syntax supported by SQLiteDialect");
  }

  public String getAddPrimaryKeyConstraintString(String constraintName) {
    throw new UnsupportedOperationException(
        "No add primary key syntax supported by SQLiteDialect");
  }

  public boolean supportsIfExistsBeforeTableName() {
    return true;
  }

  public boolean supportsCascadeDelete() {
    return false;
  }
}

1 comment: