diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/Dialect.java b/hibernate-core/src/main/java/org/hibernate/dialect/Dialect.java
index fd8da06721..75d3c83074 100644
--- a/hibernate-core/src/main/java/org/hibernate/dialect/Dialect.java
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/Dialect.java
@@ -39,6 +39,7 @@ import java.util.Map;
import java.util.Properties;
import java.util.Set;
+import org.hibernate.engine.spi.RowSelection;
import org.jboss.logging.Logger;
import org.hibernate.HibernateException;
@@ -58,6 +59,8 @@ import org.hibernate.dialect.lock.PessimisticForceIncrementLockingStrategy;
import org.hibernate.dialect.lock.PessimisticReadSelectLockingStrategy;
import org.hibernate.dialect.lock.PessimisticWriteSelectLockingStrategy;
import org.hibernate.dialect.lock.SelectLockingStrategy;
+import org.hibernate.dialect.pagination.LegacyLimitHandler;
+import org.hibernate.dialect.pagination.LimitHandler;
import org.hibernate.engine.jdbc.LobCreator;
import org.hibernate.engine.spi.SessionImplementor;
import org.hibernate.exception.spi.ConversionContext;
@@ -935,7 +938,9 @@ public abstract class Dialect implements ConversionContext {
* via a SQL clause?
*
* @return True if this dialect supports some form of LIMIT.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean supportsLimit() {
return false;
}
@@ -945,7 +950,9 @@ public abstract class Dialect implements ConversionContext {
* support specifying an offset?
*
* @return True if the dialect supports an offset within the limit support.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean supportsLimitOffset() {
return supportsLimit();
}
@@ -955,7 +962,9 @@ public abstract class Dialect implements ConversionContext {
* parameters) for its limit/offset?
*
* @return True if bind variables can be used; false otherwise.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean supportsVariableLimit() {
return supportsLimit();
}
@@ -965,7 +974,9 @@ public abstract class Dialect implements ConversionContext {
* Does this dialect require us to bind the parameters in reverse order?
*
* @return true if the correct order is limit, offset
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean bindLimitParametersInReverseOrder() {
return false;
}
@@ -975,7 +986,9 @@ public abstract class Dialect implements ConversionContext {
* SELECT statement, rather than at the end?
*
* @return true if limit parameters should come before other parameters
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean bindLimitParametersFirst() {
return false;
}
@@ -995,7 +1008,9 @@ public abstract class Dialect implements ConversionContext {
* So essentially, is limit relative from offset? Or is limit absolute?
*
* @return True if limit is relative from offset; false otherwise.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean useMaxForLimit() {
return false;
}
@@ -1005,7 +1020,9 @@ public abstract class Dialect implements ConversionContext {
* to the SQL query. This option forces that the limit be written to the SQL query.
*
* @return True to force limit into SQL query even if none specified in Hibernate query; false otherwise.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public boolean forceLimitUsage() {
return false;
}
@@ -1017,7 +1034,9 @@ public abstract class Dialect implements ConversionContext {
* @param offset The offset of the limit
* @param limit The limit of the limit ;)
* @return The modified query statement with the limit applied.
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public String getLimitString(String query, int offset, int limit) {
return getLimitString( query, ( offset > 0 || forceLimitUsage() ) );
}
@@ -1038,7 +1057,9 @@ public abstract class Dialect implements ConversionContext {
* @param query The query to which to apply the limit.
* @param hasOffset Is the query requesting an offset?
* @return the modified SQL
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
protected String getLimitString(String query, boolean hasOffset) {
throw new UnsupportedOperationException( "Paged queries not supported by " + getClass().getName());
}
@@ -1052,16 +1073,27 @@ public abstract class Dialect implements ConversionContext {
* to injecting the limit values into the SQL string.
*
* @param zeroBasedFirstResult The user-supplied, zero-based first row offset.
- *
* @return The corresponding db/dialect specific offset.
- *
* @see org.hibernate.Query#setFirstResult
* @see org.hibernate.Criteria#setFirstResult
+ * @deprecated {@link #buildLimitHandler(String, RowSelection)} should be overridden instead.
*/
+ @Deprecated
public int convertToFirstRowValue(int zeroBasedFirstResult) {
return zeroBasedFirstResult;
}
+ /**
+ * Build delegate managing LIMIT clause.
+ *
+ * @param sql SQL query.
+ * @param selection Selection criteria. {@code null} in case of unlimited number of rows.
+ * @return LIMIT clause delegate.
+ */
+ public LimitHandler buildLimitHandler(String sql, RowSelection selection) {
+ return new LegacyLimitHandler( this, sql, selection );
+ }
+
// lock acquisition support ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/SQLServer2005Dialect.java b/hibernate-core/src/main/java/org/hibernate/dialect/SQLServer2005Dialect.java
index b3c01018b9..4ee4697b8a 100644
--- a/hibernate-core/src/main/java/org/hibernate/dialect/SQLServer2005Dialect.java
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/SQLServer2005Dialect.java
@@ -25,14 +25,15 @@ package org.hibernate.dialect;
import java.sql.SQLException;
import java.sql.Types;
-import java.util.regex.Matcher;
-import java.util.regex.Pattern;
import org.hibernate.JDBCException;
import org.hibernate.LockMode;
import org.hibernate.LockOptions;
import org.hibernate.QueryTimeoutException;
import org.hibernate.dialect.function.NoArgSQLFunction;
+import org.hibernate.dialect.pagination.LimitHandler;
+import org.hibernate.dialect.pagination.SQLServer2005LimitHandler;
+import org.hibernate.engine.spi.RowSelection;
import org.hibernate.exception.LockTimeoutException;
import org.hibernate.exception.spi.SQLExceptionConversionDelegate;
import org.hibernate.internal.util.JdbcExceptionHelper;
@@ -42,19 +43,11 @@ import org.hibernate.type.StandardBasicTypes;
* A dialect for Microsoft SQL 2005. (HHH-3936 fix)
*
* @author Yoryos Valotasios
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
*/
public class SQLServer2005Dialect extends SQLServerDialect {
- private static final String SELECT = "select";
- private static final String FROM = "from";
- private static final String DISTINCT = "distinct";
- private static final String ORDER_BY = "order by";
private static final int MAX_LENGTH = 8000;
- /**
- * Regular expression for stripping alias
- */
- private static final Pattern ALIAS_PATTERN = Pattern.compile( "\\sas\\s[^,]+(,?)" );
-
public SQLServer2005Dialect() {
// HHH-3965 fix
// As per http://www.sql-server-helper.com/faq/sql-server-2005-varchar-max-p01.aspx
@@ -78,139 +71,8 @@ public class SQLServer2005Dialect extends SQLServerDialect {
}
@Override
- public boolean supportsLimitOffset() {
- return true;
- }
-
- @Override
- public boolean bindLimitParametersFirst() {
- return false;
- }
-
- @Override
- public boolean supportsVariableLimit() {
- return true;
- }
-
- @Override
- public int convertToFirstRowValue(int zeroBasedFirstResult) {
- // Our dialect paginated results aren't zero based. The first row should get the number 1 and so on
- return zeroBasedFirstResult + 1;
- }
-
- @Override
- public String getLimitString(String query, int offset, int limit) {
- // We transform the query to one with an offset and limit if we have an offset and limit to bind
- if ( offset > 1 || limit > 1 ) {
- return getLimitString( query, true );
- }
- return query;
- }
-
- /**
- * Add a LIMIT clause to the given SQL SELECT (HHH-2655: ROW_NUMBER for Paging)
- *
- * The LIMIT SQL will look like:
- *
- *
- * WITH query AS (
- * original_select_clause_without_distinct_and_order_by,
- * ROW_NUMBER() OVER ([ORDER BY CURRENT_TIMESTAMP | original_order_by_clause]) as __hibernate_row_nr__
- * original_from_clause
- * original_where_clause
- * group_by_if_originally_select_distinct
- * )
- * SELECT * FROM query WHERE __hibernate_row_nr__ >= offset AND __hibernate_row_nr__ < offset + last
- *
- *
- * @param querySqlString The SQL statement to base the limit query off of.
- * @param hasOffset Is the query requesting an offset?
- *
- * @return A new SQL statement with the LIMIT clause applied.
- */
- @Override
- public String getLimitString(String querySqlString, boolean hasOffset) {
- StringBuilder sb = new StringBuilder( querySqlString.trim() );
-
- int orderByIndex = shallowIndexOfWord( sb, ORDER_BY, 0 );
- CharSequence orderby = orderByIndex > 0 ? sb.subSequence( orderByIndex, sb.length() )
- : "ORDER BY CURRENT_TIMESTAMP";
-
- // Delete the order by clause at the end of the query
- if ( orderByIndex > 0 ) {
- sb.delete( orderByIndex, orderByIndex + orderby.length() );
- }
-
- // HHH-5715 bug fix
- replaceDistinctWithGroupBy( sb );
-
- insertRowNumberFunction( sb, orderby );
-
- // Wrap the query within a with statement:
- sb.insert( 0, "WITH query AS (" ).append( ") SELECT * FROM query " );
- sb.append( "WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?" );
-
- return sb.toString();
- }
-
- /**
- * Utility method that checks if the given sql query is a select distinct one and if so replaces the distinct select
- * with an equivalent simple select with a group by clause.
- *
- * @param sql an sql query
- */
- protected static void replaceDistinctWithGroupBy(StringBuilder sql) {
- int distinctIndex = shallowIndexOfWord( sql, DISTINCT, 0 );
- int selectEndIndex = shallowIndexOfWord( sql, FROM, 0 );
- if (distinctIndex > 0 && distinctIndex < selectEndIndex) {
- sql.delete( distinctIndex, distinctIndex + DISTINCT.length() + " ".length());
- sql.append( " group by" ).append( getSelectFieldsWithoutAliases( sql ) );
- }
- }
-
- public static final String SELECT_WITH_SPACE = SELECT + ' ';
-
- /**
- * This utility method searches the given sql query for the fields of the select statement and returns them without
- * the aliases.
- *
- * @param sql sql query
- *
- * @return the fields of the select statement without their alias
- */
- protected static CharSequence getSelectFieldsWithoutAliases(StringBuilder sql) {
- final int selectStartPos = shallowIndexOf( sql, SELECT_WITH_SPACE, 0 );
- final int fromStartPos = shallowIndexOfWord( sql, FROM, selectStartPos );
- String select = sql.substring( selectStartPos + SELECT.length(), fromStartPos );
-
- // Strip the as clauses
- return stripAliases( select );
- }
-
- /**
- * Utility method that strips the aliases.
- *
- * @param str string to replace the as statements
- *
- * @return a string without the as statements
- */
- protected static String stripAliases(String str) {
- Matcher matcher = ALIAS_PATTERN.matcher( str );
- return matcher.replaceAll( "$1" );
- }
-
- /**
- * We must place the row_number function at the end of select clause.
- *
- * @param sql the initial sql query without the order by clause
- * @param orderby the order by clause of the query
- */
- protected void insertRowNumberFunction(StringBuilder sql, CharSequence orderby) {
- // Find the end of the select clause
- int selectEndIndex = shallowIndexOfWord( sql, FROM, 0 );
-
- // Insert after the select clause the row_number() function:
- sql.insert( selectEndIndex - 1, ", ROW_NUMBER() OVER (" + orderby + ") as __hibernate_row_nr__" );
+ public LimitHandler buildLimitHandler(String sql, RowSelection selection) {
+ return new SQLServer2005LimitHandler( sql, selection );
}
@Override // since SQLServer2005 the nowait hint is supported
@@ -235,50 +97,6 @@ public class SQLServer2005Dialect extends SQLServerDialect {
}
}
- /**
- * Returns index of the first case-insensitive match of search term surrounded by spaces
- * that is not enclosed in parentheses.
- *
- * @param sb String to search.
- * @param search Search term.
- * @param fromIndex The index from which to start the search.
- * @return Position of the first match, or {@literal -1} if not found.
- */
- private static int shallowIndexOfWord(final StringBuilder sb, final String search, int fromIndex) {
- final int index = shallowIndexOf( sb, ' ' + search + ' ', fromIndex );
- return index != -1 ? ( index + 1 ) : -1; // In case of match adding one because of space placed in front of search term.
- }
-
- /**
- * Returns index of the first case-insensitive match of search term that is not enclosed in parentheses.
- *
- * @param sb String to search.
- * @param search Search term.
- * @param fromIndex The index from which to start the search.
- * @return Position of the first match, or {@literal -1} if not found.
- */
- private static int shallowIndexOf(StringBuilder sb, String search, int fromIndex) {
- final String lowercase = sb.toString().toLowerCase(); // case-insensitive match
- final int len = lowercase.length();
- final int searchlen = search.length();
- int pos = -1, depth = 0, cur = fromIndex;
- do {
- pos = lowercase.indexOf( search, cur );
- if ( pos != -1 ) {
- for ( int iter = cur; iter < pos; iter++ ) {
- char c = sb.charAt( iter );
- if ( c == '(' ) {
- depth = depth + 1;
- }
- else if ( c == ')' ) {
- depth = depth - 1;
- }
- }
- cur = pos + searchlen;
- }
- } while ( cur < len && depth != 0 && pos != -1 );
- return depth == 0 ? pos : -1;
- }
@Override
public SQLExceptionConversionDelegate buildSQLExceptionConversionDelegate() {
return new SQLExceptionConversionDelegate() {
@@ -286,7 +104,7 @@ public class SQLServer2005Dialect extends SQLServerDialect {
public JDBCException convert(SQLException sqlException, String message, String sql) {
final String sqlState = JdbcExceptionHelper.extractSqlState( sqlException );
final int errorCode = JdbcExceptionHelper.extractErrorCode( sqlException );
- if( "HY008".equals( sqlState )){
+ if ( "HY008".equals( sqlState ) ) {
throw new QueryTimeoutException( message, sqlException, sql );
}
if (1222 == errorCode ) {
@@ -296,7 +114,4 @@ public class SQLServer2005Dialect extends SQLServerDialect {
}
};
}
-
-
-
}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/AbstractLimitHandler.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/AbstractLimitHandler.java
new file mode 100644
index 0000000000..f517b46482
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/AbstractLimitHandler.java
@@ -0,0 +1,168 @@
+package org.hibernate.dialect.pagination;
+
+import java.sql.PreparedStatement;
+import java.sql.SQLException;
+
+import org.hibernate.engine.spi.RowSelection;
+
+/**
+ * Default implementation of {@link LimitHandler} interface.
+ *
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public abstract class AbstractLimitHandler implements LimitHandler {
+ protected final String sql;
+ protected final RowSelection selection;
+
+ /**
+ * Default constructor. SQL query and selection criteria required to allow LIMIT clause pre-processing.
+ *
+ * @param sql SQL query.
+ * @param selection Selection criteria. {@code null} in case of unlimited number of rows.
+ */
+ public AbstractLimitHandler(String sql, RowSelection selection) {
+ this.sql = sql;
+ this.selection = selection;
+ }
+
+ public boolean supportsLimit() {
+ return false;
+ }
+
+ public boolean supportsLimitOffset() {
+ return supportsLimit();
+ }
+
+ /**
+ * Does this handler support bind variables (i.e., prepared statement
+ * parameters) for its limit/offset?
+ *
+ * @return True if bind variables can be used; false otherwise.
+ */
+ public boolean supportsVariableLimit() {
+ return supportsLimit();
+ }
+
+ /**
+ * ANSI SQL defines the LIMIT clause to be in the form LIMIT offset, limit.
+ * Does this dialect require us to bind the parameters in reverse order?
+ *
+ * @return true if the correct order is limit, offset
+ */
+ public boolean bindLimitParametersInReverseOrder() {
+ return false;
+ }
+
+ /**
+ * Does the LIMIT clause come at the start of the
+ * SELECT statement, rather than at the end?
+ *
+ * @return true if limit parameters should come before other parameters
+ */
+ public boolean bindLimitParametersFirst() {
+ return false;
+ }
+
+ /**
+ * Does the LIMIT clause take a "maximum" row number instead
+ * of a total number of returned rows?
+ *
+ * This is easiest understood via an example. Consider you have a table
+ * with 20 rows, but you only want to retrieve rows number 11 through 20.
+ * Generally, a limit with offset would say that the offset = 11 and the
+ * limit = 10 (we only want 10 rows at a time); this is specifying the
+ * total number of returned rows. Some dialects require that we instead
+ * specify offset = 11 and limit = 20, where 20 is the "last" row we want
+ * relative to offset (i.e. total number of rows = 20 - 11 = 9)
+ *
+ * So essentially, is limit relative from offset? Or is limit absolute?
+ *
+ * @return True if limit is relative from offset; false otherwise.
+ */
+ public boolean useMaxForLimit() {
+ return false;
+ }
+
+ /**
+ * Generally, if there is no limit applied to a Hibernate query we do not apply any limits
+ * to the SQL query. This option forces that the limit be written to the SQL query.
+ *
+ * @return True to force limit into SQL query even if none specified in Hibernate query; false otherwise.
+ */
+ public boolean forceLimitUsage() {
+ return false;
+ }
+
+ /**
+ * Hibernate APIs explicitly state that setFirstResult() should be a zero-based offset. Here we allow the
+ * Dialect a chance to convert that value based on what the underlying db or driver will expect.
+ *
+ * NOTE: what gets passed into {@link #AbstractLimitHandler(String, RowSelection)} is the zero-based offset.
+ * Dialects which do not {@link #supportsVariableLimit} should take care to perform any needed first-row-conversion
+ * calls prior to injecting the limit values into the SQL string.
+ *
+ * @param zeroBasedFirstResult The user-supplied, zero-based first row offset.
+ *
+ * @return The corresponding db/dialect specific offset.
+ *
+ * @see org.hibernate.Query#setFirstResult
+ * @see org.hibernate.Criteria#setFirstResult
+ */
+ public int convertToFirstRowValue(int zeroBasedFirstResult) {
+ return zeroBasedFirstResult;
+ }
+
+ public String getProcessedSql() {
+ throw new UnsupportedOperationException( "Paged queries not supported by " + getClass().getName() );
+ }
+
+ public int bindLimitParametersAtStartOfQuery(PreparedStatement statement, int index)
+ throws SQLException {
+ return bindLimitParametersFirst() ? bindLimitParameters( statement, index ) : 0;
+ }
+
+ public int bindLimitParametersAtEndOfQuery(PreparedStatement statement, int index)
+ throws SQLException {
+ return !bindLimitParametersFirst() ? bindLimitParameters( statement, index ) : 0;
+ }
+
+ public void setMaxRows(PreparedStatement statement) throws SQLException {
+ }
+
+ /**
+ * Default implementation of binding parameter values needed by the LIMIT clause.
+ *
+ * @param statement Statement to which to bind limit parameter values.
+ * @param index Index from which to start binding.
+ * @return The number of parameter values bound.
+ * @throws SQLException Indicates problems binding parameter values.
+ */
+ protected int bindLimitParameters(PreparedStatement statement, int index)
+ throws SQLException {
+ if ( !supportsVariableLimit() || !LimitHelper.hasMaxRows( selection ) ) {
+ return 0;
+ }
+ int firstRow = convertToFirstRowValue( LimitHelper.getFirstRow( selection ) );
+ int lastRow = getMaxOrLimit();
+ boolean hasFirstRow = supportsLimitOffset() && ( firstRow > 0 || forceLimitUsage() );
+ boolean reverse = bindLimitParametersInReverseOrder();
+ if ( hasFirstRow ) {
+ statement.setInt( index + ( reverse ? 1 : 0 ), firstRow );
+ }
+ statement.setInt( index + ( reverse || !hasFirstRow ? 0 : 1 ), lastRow );
+ return hasFirstRow ? 2 : 1;
+ }
+
+ /**
+ * Some dialect-specific LIMIT clauses require the maximum last row number
+ * (aka, first_row_number + total_row_count), while others require the maximum
+ * returned row count (the total maximum number of rows to return).
+ *
+ * @return The appropriate value to bind into the limit clause.
+ */
+ protected int getMaxOrLimit() {
+ final int firstRow = convertToFirstRowValue( LimitHelper.getFirstRow( selection ) );
+ final int lastRow = selection.getMaxRows();
+ return useMaxForLimit() ? lastRow + firstRow : lastRow;
+ }
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LegacyLimitHandler.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LegacyLimitHandler.java
new file mode 100644
index 0000000000..e3545177d7
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LegacyLimitHandler.java
@@ -0,0 +1,58 @@
+package org.hibernate.dialect.pagination;
+
+import org.hibernate.dialect.Dialect;
+import org.hibernate.engine.spi.RowSelection;
+
+/**
+ * Limit handler that delegates all operations to the underlying dialect.
+ *
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public class LegacyLimitHandler extends AbstractLimitHandler {
+ private final Dialect dialect;
+
+ public LegacyLimitHandler(Dialect dialect, String sql, RowSelection selection) {
+ super( sql, selection );
+ this.dialect = dialect;
+ }
+
+ public boolean supportsLimit() {
+ return dialect.supportsLimit();
+ }
+
+ public boolean supportsLimitOffset() {
+ return dialect.supportsLimitOffset();
+ }
+
+ public boolean supportsVariableLimit() {
+ return dialect.supportsVariableLimit();
+ }
+
+ public boolean bindLimitParametersInReverseOrder() {
+ return dialect.bindLimitParametersInReverseOrder();
+ }
+
+ public boolean bindLimitParametersFirst() {
+ return dialect.bindLimitParametersFirst();
+ }
+
+ public boolean useMaxForLimit() {
+ return dialect.useMaxForLimit();
+ }
+
+ public boolean forceLimitUsage() {
+ return dialect.forceLimitUsage();
+ }
+
+ public int convertToFirstRowValue(int zeroBasedFirstResult) {
+ return dialect.convertToFirstRowValue( zeroBasedFirstResult );
+ }
+
+ public String getProcessedSql() {
+ boolean useLimitOffset = supportsLimit() && supportsLimitOffset()
+ && LimitHelper.hasFirstRow( selection ) && LimitHelper.hasMaxRows( selection );
+ return dialect.getLimitString(
+ sql, useLimitOffset ? LimitHelper.getFirstRow( selection ) : 0, getMaxOrLimit()
+ );
+ }
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHandler.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHandler.java
new file mode 100644
index 0000000000..ea0b0dbf4b
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHandler.java
@@ -0,0 +1,66 @@
+package org.hibernate.dialect.pagination;
+
+import java.sql.PreparedStatement;
+import java.sql.SQLException;
+
+import org.hibernate.engine.spi.RowSelection;
+
+/**
+ * Contract defining dialect-specific LIMIT clause handling. Typically implementers might consider extending
+ * {@link AbstractLimitHandler} class.
+ *
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public interface LimitHandler {
+ /**
+ * Does this handler support some form of limiting query results
+ * via a SQL clause?
+ *
+ * @return True if this handler supports some form of LIMIT.
+ */
+ public boolean supportsLimit();
+
+ /**
+ * Does this handler's LIMIT support (if any) additionally
+ * support specifying an offset?
+ *
+ * @return True if the handler supports an offset within the limit support.
+ */
+ public boolean supportsLimitOffset();
+
+ /**
+ * Return processed SQL query.
+ *
+ * @return Query statement with LIMIT clause applied.
+ */
+ public String getProcessedSql();
+
+ /**
+ * Bind parameter values needed by the LIMIT clause before original SELECT statement.
+ *
+ * @param statement Statement to which to bind limit parameter values.
+ * @param index Index from which to start binding.
+ * @return The number of parameter values bound.
+ * @throws SQLException Indicates problems binding parameter values.
+ */
+ public int bindLimitParametersAtStartOfQuery(PreparedStatement statement, int index) throws SQLException;
+
+ /**
+ * Bind parameter values needed by the LIMIT clause after original SELECT statement.
+ *
+ * @param statement Statement to which to bind limit parameter values.
+ * @param index Index from which to start binding.
+ * @return The number of parameter values bound.
+ * @throws SQLException Indicates problems binding parameter values.
+ */
+ public int bindLimitParametersAtEndOfQuery(PreparedStatement statement, int index) throws SQLException;
+
+ /**
+ * Use JDBC API to limit the number of rows returned by the SQL query. Typically handlers that do not
+ * support LIMIT clause should implement this method.
+ *
+ * @param statement Statement which number of returned rows shall be limited.
+ * @throws SQLException Indicates problems while limiting maximum rows returned.
+ */
+ public void setMaxRows(PreparedStatement statement) throws SQLException;
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHelper.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHelper.java
new file mode 100644
index 0000000000..4a43735dca
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/LimitHelper.java
@@ -0,0 +1,24 @@
+package org.hibernate.dialect.pagination;
+
+import org.hibernate.engine.spi.RowSelection;
+
+/**
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public class LimitHelper {
+ public static boolean useLimit(LimitHandler limitHandler, RowSelection selection) {
+ return limitHandler.supportsLimit() && hasMaxRows( selection );
+ }
+
+ public static boolean hasFirstRow(RowSelection selection) {
+ return getFirstRow( selection ) > 0;
+ }
+
+ public static int getFirstRow(RowSelection selection) {
+ return ( selection == null || selection.getFirstRow() == null ) ? 0 : selection.getFirstRow();
+ }
+
+ public static boolean hasMaxRows(RowSelection selection) {
+ return selection != null && selection.getMaxRows() != null && selection.getMaxRows() > 0;
+ }
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/NoopLimitHandler.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/NoopLimitHandler.java
new file mode 100644
index 0000000000..203902768a
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/NoopLimitHandler.java
@@ -0,0 +1,35 @@
+package org.hibernate.dialect.pagination;
+
+import java.sql.PreparedStatement;
+import java.sql.SQLException;
+
+import org.hibernate.engine.spi.RowSelection;
+
+/**
+ * Handler not supporting query LIMIT clause. JDBC API is used to set maximum number of returned rows.
+ *
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public class NoopLimitHandler extends AbstractLimitHandler {
+ public NoopLimitHandler(String sql, RowSelection selection) {
+ super( sql, selection );
+ }
+
+ public String getProcessedSql() {
+ return sql;
+ }
+
+ public int bindLimitParametersAtStartOfQuery(PreparedStatement statement, int index) {
+ return 0;
+ }
+
+ public int bindLimitParametersAtEndOfQuery(PreparedStatement statement, int index) {
+ return 0;
+ }
+
+ public void setMaxRows(PreparedStatement statement) throws SQLException {
+ if ( LimitHelper.hasMaxRows( selection ) ) {
+ statement.setMaxRows( selection.getMaxRows() + convertToFirstRowValue( LimitHelper.getFirstRow( selection ) ) );
+ }
+ }
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/dialect/pagination/SQLServer2005LimitHandler.java b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/SQLServer2005LimitHandler.java
new file mode 100644
index 0000000000..8930a4d583
--- /dev/null
+++ b/hibernate-core/src/main/java/org/hibernate/dialect/pagination/SQLServer2005LimitHandler.java
@@ -0,0 +1,263 @@
+package org.hibernate.dialect.pagination;
+
+import java.sql.PreparedStatement;
+import java.sql.SQLException;
+import java.util.LinkedList;
+import java.util.List;
+import java.util.regex.Matcher;
+import java.util.regex.Pattern;
+
+import org.hibernate.engine.spi.RowSelection;
+import org.hibernate.internal.util.StringHelper;
+
+/**
+ * LIMIT clause handler compatible with SQL Server 2005 and later.
+ *
+ * @author Lukasz Antoniak (lukasz dot antoniak at gmail dot com)
+ */
+public class SQLServer2005LimitHandler extends AbstractLimitHandler {
+ private static final String SELECT = "select";
+ private static final String SELECT_WITH_SPACE = SELECT + ' ';
+ private static final String FROM = "from";
+ private static final String DISTINCT = "distinct";
+ private static final String ORDER_BY = "order by";
+
+ private static final Pattern ALIAS_PATTERN = Pattern.compile( "(?i)\\sas\\s(.)+$" );
+
+ private boolean topAdded = false; // Flag indicating whether TOP(?) expression has been added to the original query.
+ private boolean hasOffset = true; // True if offset greater than 0.
+
+ public SQLServer2005LimitHandler(String sql, RowSelection selection) {
+ super( sql, selection );
+ }
+
+ @Override
+ public boolean supportsLimit() {
+ return true;
+ }
+
+ @Override
+ public boolean useMaxForLimit() {
+ return true;
+ }
+
+ @Override
+ public boolean supportsLimitOffset() {
+ return true;
+ }
+
+ @Override
+ public boolean supportsVariableLimit() {
+ return true;
+ }
+
+ @Override
+ public int convertToFirstRowValue(int zeroBasedFirstResult) {
+ // Our dialect paginated results aren't zero based. The first row should get the number 1 and so on
+ return zeroBasedFirstResult + 1;
+ }
+
+ /**
+ * Add a LIMIT clause to the given SQL SELECT (HHH-2655: ROW_NUMBER for Paging)
+ *
+ * The LIMIT SQL will look like:
+ *
+ *
+ * WITH query AS (
+ * SELECT inner_query.*
+ * , ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__
+ * FROM ( original_query_with_top_if_order_by_present_and_all_aliased_columns ) inner_query
+ * )
+ * SELECT alias_list FROM query WHERE __hibernate_row_nr__ >= offset AND __hibernate_row_nr__ < offset + last
+ *
+ *
+ * When offset equals {@literal 0}, only {@literal TOP(?)} expression is added to the original query.
+ *
+ * @return A new SQL statement with the LIMIT clause applied.
+ */
+ @Override
+ public String getProcessedSql() {
+ StringBuilder sb = new StringBuilder( sql );
+ if ( sb.charAt( sb.length() - 1 ) == ';' ) {
+ sb.setLength( sb.length() - 1 );
+ }
+
+ if ( LimitHelper.hasFirstRow( selection ) ) {
+ final String selectClause = fillAliasInSelectClause( sb );
+
+ int orderByIndex = shallowIndexOfWord( sb, ORDER_BY, 0 );
+ if ( orderByIndex > 0 ) {
+ // ORDER BY requires using TOP.
+ addTopExpression( sb );
+ }
+
+ encloseWithOuterQuery( sb );
+
+ // Wrap the query within a with statement:
+ sb.insert( 0, "WITH query AS (" ).append( ") SELECT " ).append( selectClause ).append( " FROM query " );
+ sb.append( "WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?" );
+ }
+ else {
+ hasOffset = false;
+ addTopExpression( sb );
+ }
+
+ return sb.toString();
+ }
+
+ @Override
+ public int bindLimitParametersAtStartOfQuery(PreparedStatement statement, int index) throws SQLException {
+ if ( topAdded ) {
+ statement.setInt( index, getMaxOrLimit() - 1 ); // Binding TOP(?).
+ return 1;
+ }
+ return 0;
+ }
+
+ @Override
+ public int bindLimitParametersAtEndOfQuery(PreparedStatement statement, int index) throws SQLException {
+ return hasOffset ? super.bindLimitParametersAtEndOfQuery( statement, index ) : 0;
+ }
+
+ /**
+ * Adds missing aliases in provided SELECT clause and returns coma-separated list of them.
+ *
+ * @param sb SQL query.
+ *
+ * @return List of aliases separated with comas.
+ */
+ protected String fillAliasInSelectClause(StringBuilder sb) {
+ final List aliases = new LinkedList();
+ final int startPos = shallowIndexOf( sb, SELECT_WITH_SPACE, 0 );
+ int endPos = shallowIndexOfWord( sb, FROM, startPos );
+ int nextComa = startPos;
+ int prevComa = startPos;
+ int unique = 0;
+
+ while ( nextComa != -1 ) {
+ prevComa = nextComa;
+ nextComa = shallowIndexOf( sb, ",", nextComa );
+ if ( nextComa > endPos ) {
+ break;
+ }
+ if ( nextComa != -1 ) {
+ String expression = sb.substring( prevComa, nextComa );
+ String alias = getAlias( expression );
+ if ( alias == null ) {
+ // Inserting alias. It is unlikely that we would have to add alias, but just in case.
+ alias = StringHelper.generateAlias( "page", unique );
+ sb.insert( nextComa, " as " + alias );
+ ++unique;
+ nextComa += ( " as " + alias ).length();
+ }
+ aliases.add( alias );
+ ++nextComa;
+ }
+ }
+ // Processing last column.
+ endPos = shallowIndexOfWord( sb, FROM, startPos ); // Refreshing end position, because we might have inserted new alias.
+ String expression = sb.substring( prevComa, endPos );
+ String alias = getAlias( expression );
+ if ( alias == null ) {
+ // Inserting alias. It is unlikely that we would have to add alias, but just in case.
+ alias = StringHelper.generateAlias( "page", unique );
+ sb.insert( endPos - 1, " as " + alias );
+ }
+ aliases.add( alias );
+
+ return StringHelper.join( ", ", aliases.iterator() );
+ }
+
+ /**
+ * Returns alias of provided single column selection or {@code null} if not found.
+ * Alias should be preceded with {@code AS} keyword.
+ *
+ * @param expression Single column select expression.
+ *
+ * @return Column alias.
+ */
+ private String getAlias(String expression) {
+ Matcher matcher = ALIAS_PATTERN.matcher( expression );
+ if ( matcher.find() ) {
+ return matcher.group( 0 ).replaceFirst( "(?i)\\sas\\s", "" ).trim();
+ }
+ return null;
+ }
+
+ /**
+ * Encloses original SQL statement with outer query that provides {@literal __hibernate_row_nr__} column.
+ *
+ * @param sql SQL query.
+ */
+ protected void encloseWithOuterQuery(StringBuilder sql) {
+ sql.insert( 0, "SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " );
+ sql.append( " ) inner_query " );
+ }
+
+ /**
+ * Adds {@code TOP} expression. Parameter value is bind in
+ * {@link #bindLimitParametersAtStartOfQuery(PreparedStatement, int)} method.
+ *
+ * @param sql SQL query.
+ */
+ protected void addTopExpression(StringBuilder sql) {
+ final int distinctStartPos = shallowIndexOfWord( sql, DISTINCT, 0 );
+ if ( distinctStartPos > 0 ) {
+ // Place TOP after DISTINCT.
+ sql.insert( distinctStartPos + DISTINCT.length(), " TOP(?)" );
+ }
+ else {
+ final int selectStartPos = shallowIndexOf( sql, SELECT_WITH_SPACE, 0 );
+ // Place TOP after SELECT.
+ sql.insert( selectStartPos + SELECT.length(), " TOP(?)" );
+ }
+ topAdded = true;
+ }
+
+ /**
+ * Returns index of the first case-insensitive match of search term surrounded by spaces
+ * that is not enclosed in parentheses.
+ *
+ * @param sb String to search.
+ * @param search Search term.
+ * @param fromIndex The index from which to start the search.
+ *
+ * @return Position of the first match, or {@literal -1} if not found.
+ */
+ private static int shallowIndexOfWord(final StringBuilder sb, final String search, int fromIndex) {
+ final int index = shallowIndexOf( sb, ' ' + search + ' ', fromIndex );
+ return index != -1 ? ( index + 1 ) : -1; // In case of match adding one because of space placed in front of search term.
+ }
+
+ /**
+ * Returns index of the first case-insensitive match of search term that is not enclosed in parentheses.
+ *
+ * @param sb String to search.
+ * @param search Search term.
+ * @param fromIndex The index from which to start the search.
+ *
+ * @return Position of the first match, or {@literal -1} if not found.
+ */
+ private static int shallowIndexOf(StringBuilder sb, String search, int fromIndex) {
+ final String lowercase = sb.toString().toLowerCase(); // case-insensitive match
+ final int len = lowercase.length();
+ final int searchlen = search.length();
+ int pos = -1, depth = 0, cur = fromIndex;
+ do {
+ pos = lowercase.indexOf( search, cur );
+ if ( pos != -1 ) {
+ for ( int iter = cur; iter < pos; iter++ ) {
+ char c = sb.charAt( iter );
+ if ( c == '(' ) {
+ depth = depth + 1;
+ }
+ else if ( c == ')' ) {
+ depth = depth - 1;
+ }
+ }
+ cur = pos + searchlen;
+ }
+ } while ( cur < len && depth != 0 && pos != -1 );
+ return depth == 0 ? pos : -1;
+ }
+}
diff --git a/hibernate-core/src/main/java/org/hibernate/hql/internal/classic/QueryTranslatorImpl.java b/hibernate-core/src/main/java/org/hibernate/hql/internal/classic/QueryTranslatorImpl.java
index 72088efc90..0202094c3b 100644
--- a/hibernate-core/src/main/java/org/hibernate/hql/internal/classic/QueryTranslatorImpl.java
+++ b/hibernate-core/src/main/java/org/hibernate/hql/internal/classic/QueryTranslatorImpl.java
@@ -953,9 +953,8 @@ public class QueryTranslatorImpl extends BasicLoader implements FilterTranslator
if ( stats ) startTime = System.currentTimeMillis();
try {
-
- PreparedStatement st = prepareQueryStatement( queryParameters, false, session );
- ResultSet rs = getResultSet( st, queryParameters.hasAutoDiscoverScalarTypes(), false, queryParameters.getRowSelection(), session );
+ final ResultSet rs = executeQueryStatement( queryParameters, false, session );
+ final PreparedStatement st = (PreparedStatement) rs.getStatement();
HolderInstantiator hi = HolderInstantiator.createClassicHolderInstantiator(holderConstructor, queryParameters.getResultTransformer());
Iterator result = new IteratorImpl( rs, st, session, queryParameters.isReadOnly( session ), returnTypes, getColumnNames(), hi );
diff --git a/hibernate-core/src/main/java/org/hibernate/loader/Loader.java b/hibernate-core/src/main/java/org/hibernate/loader/Loader.java
index 2c924c85cd..486c62ca57 100644
--- a/hibernate-core/src/main/java/org/hibernate/loader/Loader.java
+++ b/hibernate-core/src/main/java/org/hibernate/loader/Loader.java
@@ -53,6 +53,9 @@ import org.hibernate.cache.spi.QueryCache;
import org.hibernate.cache.spi.QueryKey;
import org.hibernate.collection.spi.PersistentCollection;
import org.hibernate.dialect.Dialect;
+import org.hibernate.dialect.pagination.LimitHandler;
+import org.hibernate.dialect.pagination.LimitHelper;
+import org.hibernate.dialect.pagination.NoopLimitHandler;
import org.hibernate.engine.internal.TwoPhaseLoad;
import org.hibernate.engine.jdbc.ColumnNameCache;
import org.hibernate.engine.spi.EntityKey;
@@ -818,15 +821,15 @@ public abstract class Loader {
final ResultTransformer forcedResultTransformer) throws SQLException, HibernateException {
final RowSelection selection = queryParameters.getRowSelection();
- final int maxRows = hasMaxRows( selection ) ?
+ final int maxRows = LimitHelper.hasMaxRows( selection ) ?
selection.getMaxRows() :
Integer.MAX_VALUE;
final int entitySpan = getEntityPersisters().length;
final ArrayList hydratedObjects = entitySpan == 0 ? null : new ArrayList( entitySpan * 10 );
- final PreparedStatement st = prepareQueryStatement( queryParameters, false, session );
- final ResultSet rs = getResultSet( st, queryParameters.hasAutoDiscoverScalarTypes(), queryParameters.isCallable(), selection, session );
+ final ResultSet rs = executeQueryStatement( queryParameters, false, session );
+ final PreparedStatement st = (PreparedStatement) rs.getStatement();
// would be great to move all this below here into another method that could also be used
// from the new scrolling stuff.
@@ -1633,7 +1636,7 @@ public abstract class Loader {
private void advance(final ResultSet rs, final RowSelection selection)
throws SQLException {
- final int firstRow = getFirstRow( selection );
+ final int firstRow = LimitHelper.getFirstRow( selection );
if ( firstRow != 0 ) {
if ( getFactory().getSettings().isScrollableResultSetsEnabled() ) {
// we can go straight to the first required row
@@ -1646,24 +1649,17 @@ public abstract class Loader {
}
}
- private static boolean hasMaxRows(RowSelection selection) {
- return selection != null && selection.getMaxRows() != null && selection.getMaxRows() > 0;
- }
-
- private static int getFirstRow(RowSelection selection) {
- return ( selection == null || selection.getFirstRow() == null ) ? 0 : selection.getFirstRow();
- }
-
- private int interpretFirstRow(int zeroBasedFirstResult) {
- return getFactory().getDialect().convertToFirstRowValue( zeroBasedFirstResult );
- }
-
/**
- * Should we pre-process the SQL string, adding a dialect-specific
- * LIMIT clause.
+ * Build LIMIT clause handler applicable for given selection criteria. Returns {@link NoopLimitHandler} delegate
+ * if dialect does not support LIMIT expression or processed query does not use pagination.
+ *
+ * @param sql Query string.
+ * @param selection Selection criteria.
+ * @return LIMIT clause delegate.
*/
- private static boolean useLimit(final RowSelection selection, final Dialect dialect) {
- return dialect.supportsLimit() && hasMaxRows( selection );
+ protected LimitHandler getLimitHandler(String sql, RowSelection selection) {
+ final LimitHandler limitHandler = getFactory().getDialect().buildLimitHandler( sql, selection );
+ return LimitHelper.useLimit( limitHandler, selection ) ? limitHandler : new NoopLimitHandler( sql, selection );
}
private ScrollMode getScrollMode(boolean scroll, boolean hasFirstRow, boolean useLimitOffSet, QueryParameters queryParameters) {
@@ -1678,36 +1674,48 @@ public abstract class Loader {
}
return null;
}
+
+ /**
+ * Process query string by applying filters, LIMIT clause, locks and comments if necessary.
+ * Finally execute SQL statement and advance to the first row.
+ */
+ protected ResultSet executeQueryStatement(
+ final QueryParameters queryParameters,
+ final boolean scroll,
+ final SessionImplementor session) throws SQLException {
+ // Processing query filters.
+ queryParameters.processFilters( getSQLString(), session );
+
+ // Applying LIMIT clause.
+ final LimitHandler limitHandler = getLimitHandler( queryParameters.getFilteredSQL(), queryParameters.getRowSelection() );
+ String sql = limitHandler.getProcessedSql();
+
+ // Adding locks and comments.
+ sql = preprocessSQL( sql, queryParameters, getFactory().getDialect() );
+
+ final PreparedStatement st = prepareQueryStatement( sql, queryParameters, limitHandler, scroll, session );
+ return getResultSet( st, queryParameters.getRowSelection(), limitHandler, queryParameters.hasAutoDiscoverScalarTypes(), session );
+ }
+
/**
* Obtain a PreparedStatement with all parameters pre-bound.
* Bind JDBC-style ? parameters, named parameters, and
* limit parameters.
*/
protected final PreparedStatement prepareQueryStatement(
+ final String sql,
final QueryParameters queryParameters,
+ final LimitHandler limitHandler,
final boolean scroll,
final SessionImplementor session) throws SQLException, HibernateException {
-
- queryParameters.processFilters( getSQLString(), session );
- String sql = queryParameters.getFilteredSQL();
final Dialect dialect = getFactory().getDialect();
final RowSelection selection = queryParameters.getRowSelection();
- boolean useLimit = useLimit( selection, dialect );
- boolean hasFirstRow = getFirstRow( selection ) > 0;
- boolean useLimitOffset = hasFirstRow && useLimit && dialect.supportsLimitOffset();
+ boolean useLimit = LimitHelper.useLimit( limitHandler, selection );
+ boolean hasFirstRow = LimitHelper.hasFirstRow( selection );
+ boolean useLimitOffset = hasFirstRow && useLimit && limitHandler.supportsLimitOffset();
boolean callable = queryParameters.isCallable();
final ScrollMode scrollMode = getScrollMode( scroll, hasFirstRow, useLimitOffset, queryParameters );
- if ( useLimit ) {
- sql = dialect.getLimitString(
- sql.trim(), //use of trim() here is ugly?
- useLimitOffset ? getFirstRow(selection) : 0,
- getMaxOrLimit(selection, dialect)
- );
- }
-
- sql = preprocessSQL( sql, queryParameters, dialect );
-
PreparedStatement st = session.getTransactionCoordinator().getJdbcCoordinator().getStatementPreparer().prepareQueryStatement(
sql,
callable,
@@ -1718,22 +1726,17 @@ public abstract class Loader {
int col = 1;
//TODO: can we limit stored procedures ?!
- if ( useLimit && dialect.bindLimitParametersFirst() ) {
- col += bindLimitParameters( st, col, selection );
- }
+ col += limitHandler.bindLimitParametersAtStartOfQuery( st, col );
+
if (callable) {
col = dialect.registerResultSetOutParameter( (CallableStatement)st, col );
}
col += bindParameterValues( st, queryParameters, col, session );
- if ( useLimit && !dialect.bindLimitParametersFirst() ) {
- col += bindLimitParameters( st, col, selection );
- }
+ col += limitHandler.bindLimitParametersAtEndOfQuery( st, col );
- if ( !useLimit ) {
- setMaxRows( st, selection );
- }
+ limitHandler.setMaxRows( st );
if ( selection != null ) {
if ( selection.getTimeout() != null ) {
@@ -1776,63 +1779,6 @@ public abstract class Loader {
return st;
}
- /**
- * Some dialect-specific LIMIT clauses require the maximum last row number
- * (aka, first_row_number + total_row_count), while others require the maximum
- * returned row count (the total maximum number of rows to return).
- *
- * @param selection The selection criteria
- * @param dialect The dialect
- * @return The appropriate value to bind into the limit clause.
- */
- private static int getMaxOrLimit(final RowSelection selection, final Dialect dialect) {
- final int firstRow = dialect.convertToFirstRowValue( getFirstRow( selection ) );
- final int lastRow = selection.getMaxRows();
- return dialect.useMaxForLimit() ? lastRow + firstRow : lastRow;
- }
-
- /**
- * Bind parameter values needed by the dialect-specific LIMIT clause.
- *
- * @param statement The statement to which to bind limit param values.
- * @param index The bind position from which to start binding
- * @param selection The selection object containing the limit information.
- * @return The number of parameter values bound.
- * @throws java.sql.SQLException Indicates problems binding parameter values.
- */
- private int bindLimitParameters(
- final PreparedStatement statement,
- final int index,
- final RowSelection selection) throws SQLException {
- Dialect dialect = getFactory().getDialect();
- if ( !dialect.supportsVariableLimit() ) {
- return 0;
- }
- if ( !hasMaxRows( selection ) ) {
- throw new AssertionFailure( "no max results set" );
- }
- int firstRow = interpretFirstRow( getFirstRow( selection ) );
- int lastRow = getMaxOrLimit( selection, dialect );
- boolean hasFirstRow = dialect.supportsLimitOffset() && ( firstRow > 0 || dialect.forceLimitUsage() );
- boolean reverse = dialect.bindLimitParametersInReverseOrder();
- if ( hasFirstRow ) {
- statement.setInt( index + ( reverse ? 1 : 0 ), firstRow );
- }
- statement.setInt( index + ( reverse || !hasFirstRow ? 0 : 1 ), lastRow );
- return hasFirstRow ? 2 : 1;
- }
-
- /**
- * Use JDBC API to limit the number of rows returned by the SQL query if necessary
- */
- private void setMaxRows(
- final PreparedStatement st,
- final RowSelection selection) throws SQLException {
- if ( hasMaxRows( selection ) ) {
- st.setMaxRows( selection.getMaxRows() + interpretFirstRow( getFirstRow( selection ) ) );
- }
- }
-
/**
* Bind all parameter values into the prepared statement in preparation
* for execution.
@@ -1936,24 +1882,21 @@ public abstract class Loader {
}
/**
- * Fetch a PreparedStatement, call setMaxRows and then execute it,
- * advance to the first result and return an SQL ResultSet
+ * Execute given PreparedStatement, advance to the first result and return SQL ResultSet.
*/
protected final ResultSet getResultSet(
final PreparedStatement st,
- final boolean autodiscovertypes,
- final boolean callable,
final RowSelection selection,
+ final LimitHandler limitHandler,
+ final boolean autodiscovertypes,
final SessionImplementor session)
throws SQLException, HibernateException {
- ResultSet rs = null;
try {
- Dialect dialect = getFactory().getDialect();
- rs = st.executeQuery();
+ ResultSet rs = st.executeQuery();
rs = wrapResultSetIfEnabled( rs , session );
- if ( !dialect.supportsLimitOffset() || !useLimit( selection, dialect ) ) {
+ if ( !limitHandler.supportsLimitOffset() || !LimitHelper.useLimit( limitHandler, selection ) ) {
advance( rs, selection );
}
@@ -2505,9 +2448,8 @@ public abstract class Loader {
if ( stats ) startTime = System.currentTimeMillis();
try {
-
- PreparedStatement st = prepareQueryStatement( queryParameters, true, session );
- ResultSet rs = getResultSet(st, queryParameters.hasAutoDiscoverScalarTypes(), queryParameters.isCallable(), queryParameters.getRowSelection(), session);
+ final ResultSet rs = executeQueryStatement( queryParameters, true, session );
+ final PreparedStatement st = (PreparedStatement) rs.getStatement();
if ( stats ) {
getFactory().getStatisticsImplementor().queryExecuted(
diff --git a/hibernate-core/src/main/java/org/hibernate/loader/hql/QueryLoader.java b/hibernate-core/src/main/java/org/hibernate/loader/hql/QueryLoader.java
index e699c26ff0..7e845d9b04 100644
--- a/hibernate-core/src/main/java/org/hibernate/loader/hql/QueryLoader.java
+++ b/hibernate-core/src/main/java/org/hibernate/loader/hql/QueryLoader.java
@@ -487,11 +487,11 @@ public class QueryLoader extends BasicLoader {
}
try {
- final PreparedStatement st = prepareQueryStatement( queryParameters, false, session );
if ( queryParameters.isCallable() ) {
throw new QueryException("iterate() not supported for callable statements");
}
- final ResultSet rs = getResultSet(st, queryParameters.hasAutoDiscoverScalarTypes(), false, queryParameters.getRowSelection(), session);
+ final ResultSet rs = executeQueryStatement( queryParameters, false, session );
+ final PreparedStatement st = (PreparedStatement) rs.getStatement();
final Iterator result = new IteratorImpl(
rs,
st,
diff --git a/hibernate-core/src/test/java/org/hibernate/dialect/SQLServer2005DialectTestCase.java b/hibernate-core/src/test/java/org/hibernate/dialect/SQLServer2005DialectTestCase.java
index 0d1609cd82..6ccda4ea77 100644
--- a/hibernate-core/src/test/java/org/hibernate/dialect/SQLServer2005DialectTestCase.java
+++ b/hibernate-core/src/test/java/org/hibernate/dialect/SQLServer2005DialectTestCase.java
@@ -27,6 +27,7 @@ import org.junit.After;
import org.junit.Before;
import org.junit.Test;
+import org.hibernate.engine.spi.RowSelection;
import org.hibernate.testing.TestForIssue;
import org.hibernate.testing.junit4.BaseUnitTestCase;
@@ -51,34 +52,16 @@ public class SQLServer2005DialectTestCase extends BaseUnitTestCase {
dialect = null;
}
- @Test
- public void testStripAliases() {
- String input = "some_field1 as f1, some_fild2 as f2, _field3 as f3 ";
-
- assertEquals( "some_field1, some_fild2, _field3", SQLServer2005Dialect.stripAliases(input) );
- }
-
- @Test
- public void testGetSelectFieldsWithoutAliases() {
- StringBuilder input = new StringBuilder( "select some_field1 as f12, some_fild2 as f879, _field3 as _f24674_3 from ...." );
- String output = SQLServer2005Dialect.getSelectFieldsWithoutAliases( input ).toString();
-
- assertEquals( " some_field1, some_fild2, _field3", output );
- }
-
- @Test
- public void testReplaceDistinctWithGroupBy() {
- StringBuilder input = new StringBuilder( "select distinct f1, f2 as ff, f3 from table where f1 = 5" );
- SQLServer2005Dialect.replaceDistinctWithGroupBy( input );
-
- assertEquals( "select f1, f2 as ff, f3 from table where f1 = 5 group by f1, f2, f3 ", input.toString() );
- }
-
@Test
public void testGetLimitString() {
String input = "select distinct f1 as f53245 from table849752 order by f234, f67 desc";
- assertEquals( "with query as (select f1 as f53245, row_number() over (order by f234, f67 desc) as __hibernate_row_nr__ from table849752 group by f1) select * from query where __hibernate_row_nr__ >= ? and __hibernate_row_nr__ < ?", dialect.getLimitString(input, 10, 15).toLowerCase() );
+ assertEquals(
+ "with query as (select inner_query.*, row_number() over (order by current_timestamp) as __hibernate_row_nr__ from ( " +
+ "select distinct top(?) f1 as f53245 from table849752 order by f234, f67 desc ) inner_query )" +
+ " select f53245 from query where __hibernate_row_nr__ >= ? and __hibernate_row_nr__ < ?",
+ dialect.buildLimitHandler( input, toRowSelection( 10, 15 ) ).getProcessedSql().toLowerCase()
+ );
}
@Test
@@ -91,14 +74,10 @@ public class SQLServer2005DialectTestCase extends BaseUnitTestCase {
"where persistent0_.customerid=?";
assertEquals(
- "WITH query AS (select persistent0_.rid as rid1688_, " +
- "persistent0_.deviationfromtarget as deviati16_1688_, " +
- "persistent0_.sortindex as sortindex1688_, " +
- "ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ " +
- "from m_evalstate persistent0_ " +
- "where persistent0_.customerid=?) " +
- "SELECT * FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
- dialect.getLimitString( fromColumnNameSQL, 1, 10 )
+ "WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " +
+ fromColumnNameSQL + " ) inner_query ) " +
+ "SELECT rid1688_, deviati16_1688_, sortindex1688_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
+ dialect.buildLimitHandler( fromColumnNameSQL, toRowSelection( 1, 10 ) ).getProcessedSql()
);
}
@@ -113,35 +92,29 @@ public class SQLServer2005DialectTestCase extends BaseUnitTestCase {
"where persistent0_.type='v'";
assertEquals(
- "WITH query AS (select persistent0_.id as col_0_0_, " +
- "(select max(persistent1_.acceptancedate) " +
- "from av_advisoryvariant persistent1_ " +
- "where persistent1_.clientid=persistent0_.id) as col_1_0_, " +
- "ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ " +
- "from c_customer persistent0_ " +
- "where persistent0_.type='v') " +
- "SELECT * FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
- dialect.getLimitString( subselectInSelectClauseSQL, 2, 5 )
+ "WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " +
+ subselectInSelectClauseSQL + " ) inner_query ) " +
+ "SELECT col_0_0_, col_1_0_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
+ dialect.buildLimitHandler( subselectInSelectClauseSQL, toRowSelection( 2, 5 ) ).getProcessedSql()
);
}
@Test
@TestForIssue(jiraKey = "HHH-6728")
public void testGetLimitStringCaseSensitive() {
- final String caseSensitiveSQL = "select persistent0_.id as col_0_0_, " +
- "(select case when persistent0_.name = 'Smith' then 'Neo' else persistent0_.id end) as col_1_0_ " +
+ final String caseSensitiveSQL = "select persistent0_.id, persistent0_.uid AS tmp1, " +
+ "(select case when persistent0_.name = 'Smith' then 'Neo' else persistent0_.id end) " +
"from C_Customer persistent0_ " +
"where persistent0_.type='Va' " +
"order by persistent0_.Order";
assertEquals(
- "WITH query AS (select persistent0_.id as col_0_0_, " +
- "(select case when persistent0_.name = 'Smith' then 'Neo' else persistent0_.id end) as col_1_0_, " +
- "ROW_NUMBER() OVER (order by persistent0_.Order) as __hibernate_row_nr__ " +
- "from C_Customer persistent0_ " +
- "where persistent0_.type='Va' ) " +
- "SELECT * FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
- dialect.getLimitString( caseSensitiveSQL, 1, 2 )
+ "WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " +
+ "select TOP(?) persistent0_.id as page0_, persistent0_.uid AS tmp1, " +
+ "(select case when persistent0_.name = 'Smith' then 'Neo' else persistent0_.id end) as page1_ " +
+ "from C_Customer persistent0_ where persistent0_.type='Va' order by persistent0_.Order ) " +
+ "inner_query ) SELECT page0_, tmp1, page1_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
+ dialect.buildLimitHandler( caseSensitiveSQL, toRowSelection( 1, 2 ) ).getProcessedSql()
);
}
@@ -151,10 +124,39 @@ public class SQLServer2005DialectTestCase extends BaseUnitTestCase {
final String distinctInAggregateSQL = "select aggregate_function(distinct p.n) as f1 from table849752 p order by f1";
assertEquals(
- "WITH query AS (select aggregate_function(distinct p.n) as f1, " +
- "ROW_NUMBER() OVER (order by f1) as __hibernate_row_nr__ from table849752 p ) " +
- "SELECT * FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
- dialect.getLimitString( distinctInAggregateSQL, 2, 5 )
+ "WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " +
+ "select TOP(?) aggregate_function(distinct p.n) as f1 from table849752 p order by f1 ) inner_query ) " +
+ "SELECT f1 FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
+ dialect.buildLimitHandler( distinctInAggregateSQL, toRowSelection( 2, 5 ) ).getProcessedSql()
);
}
+
+ @Test
+ @TestForIssue(jiraKey = "HHH-7370")
+ public void testGetLimitStringWithMaxOnly() {
+ final String query = "select product2x0_.id as id0_, product2x0_.description as descript2_0_ " +
+ "from Product2 product2x0_ order by product2x0_.id";
+
+ assertEquals(
+ "select TOP(?) product2x0_.id as id0_, product2x0_.description as descript2_0_ " +
+ "from Product2 product2x0_ order by product2x0_.id",
+ dialect.buildLimitHandler( query, toRowSelection( 0, 1 ) ).getProcessedSql()
+ );
+
+ final String distinctQuery = "select distinct product2x0_.id as id0_, product2x0_.description as descript2_0_ " +
+ "from Product2 product2x0_ order by product2x0_.id";
+
+ assertEquals(
+ "select distinct TOP(?) product2x0_.id as id0_, product2x0_.description as descript2_0_ " +
+ "from Product2 product2x0_ order by product2x0_.id",
+ dialect.buildLimitHandler( distinctQuery, toRowSelection( 0, 5 ) ).getProcessedSql()
+ );
+ }
+
+ private RowSelection toRowSelection(int firstRow, int maxRows) {
+ RowSelection selection = new RowSelection();
+ selection.setFirstRow( firstRow );
+ selection.setMaxRows( maxRows );
+ return selection;
+ }
}
diff --git a/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/Product2.java b/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/Product2.java
index 1a8ba95ab9..7e8d767558 100644
--- a/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/Product2.java
+++ b/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/Product2.java
@@ -45,5 +45,36 @@ public class Product2 implements Serializable {
@Column(name = "description", nullable = false)
public String description;
+ public Product2() {
+ }
+ public Product2(Integer id, String description) {
+ this.id = id;
+ this.description = description;
+ }
+
+ @Override
+ public boolean equals(Object o) {
+ if ( this == o ) return true;
+ if ( !(o instanceof Product2) ) return false;
+
+ Product2 product2 = (Product2) o;
+
+ if ( description != null ? !description.equals( product2.description ) : product2.description != null ) return false;
+ if ( id != null ? !id.equals( product2.id ) : product2.id != null ) return false;
+
+ return true;
+ }
+
+ @Override
+ public int hashCode() {
+ int result = id != null ? id.hashCode() : 0;
+ result = 31 * result + ( description != null ? description.hashCode() : 0 );
+ return result;
+ }
+
+ @Override
+ public String toString() {
+ return "Product2(id = " + id + ", description = " + description + ")";
+ }
}
diff --git a/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/SQLServerDialectTest.java b/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/SQLServerDialectTest.java
index 269cd2afee..1a74f882b4 100644
--- a/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/SQLServerDialectTest.java
+++ b/hibernate-core/src/test/java/org/hibernate/test/dialect/functional/SQLServerDialectTest.java
@@ -27,14 +27,15 @@
package org.hibernate.test.dialect.functional;
import static org.junit.Assert.assertEquals;
+import static org.junit.Assert.assertArrayEquals;
import static org.junit.Assert.assertTrue;
import java.sql.Connection;
import java.sql.ResultSet;
import java.sql.SQLException;
+import java.util.Arrays;
import java.util.List;
-import org.hibernate.HibernateException;
import org.hibernate.LockMode;
import org.hibernate.LockOptions;
import org.hibernate.Session;
@@ -42,7 +43,6 @@ import org.hibernate.Transaction;
import org.hibernate.dialect.SQLServer2005Dialect;
import org.hibernate.exception.LockTimeoutException;
import org.hibernate.exception.SQLGrammarException;
-import org.hibernate.internal.SessionFactoryImpl;
import org.hibernate.jdbc.ReturningWork;
import org.hibernate.testing.RequiresDialect;
import org.hibernate.testing.TestForIssue;
@@ -57,9 +57,8 @@ import org.junit.Test;
*/
@RequiresDialect(value = { SQLServer2005Dialect.class })
public class SQLServerDialectTest extends BaseCoreFunctionalTestCase {
-
- @TestForIssue(jiraKey = "HHH-7198")
@Test
+ @TestForIssue(jiraKey = "HHH-7198")
public void testMaxResultsSqlServerWithCaseSensitiveCollation() throws Exception {
Session s = openSession();
@@ -94,10 +93,7 @@ public class SQLServerDialectTest extends BaseCoreFunctionalTestCase {
Transaction tx = s.beginTransaction();
for ( int i = 1; i <= 20; i++ ) {
- Product2 kit = new Product2();
- kit.id = i;
- kit.description = "Kit" + i;
- s.persist( kit );
+ s.persist( new Product2( i, "Kit" + i ) );
}
s.flush();
s.clear();
@@ -118,9 +114,109 @@ public class SQLServerDialectTest extends BaseCoreFunctionalTestCase {
s.close();
}
-
- @TestForIssue(jiraKey = "HHH-3961")
@Test
+ @TestForIssue(jiraKey = "HHH-7369")
+ public void testPaginationWithScalarQuery() throws Exception {
+ Session s = openSession();
+ Transaction tx = s.beginTransaction();
+
+ for ( int i = 0; i < 10; i++ ) {
+ s.persist( new Product2( i, "Kit" + i ) );
+ }
+ s.flush();
+ s.clear();
+
+ List list = s.createSQLQuery( "select id from Product2 where description like 'Kit%' order by id" ).list();
+ assertEquals(Integer.class, list.get(0).getClass()); // scalar result is an Integer
+
+ list = s.createSQLQuery( "select id from Product2 where description like 'Kit%' order by id" ).setFirstResult( 2 ).setMaxResults( 2 ).list();
+ assertEquals(Integer.class, list.get(0).getClass()); // this fails without patch, as result suddenly has become an array
+
+ // same once again with alias
+ list = s.createSQLQuery( "select id as myint from Product2 where description like 'Kit%' order by id asc" ).setFirstResult( 2 ).setMaxResults( 2 ).list();
+ assertEquals(Integer.class, list.get(0).getClass());
+
+ tx.rollback();
+ s.close();
+ }
+
+ @Test
+ @TestForIssue(jiraKey = "HHH-7368")
+ public void testPaginationWithTrailingSemicolon() throws Exception {
+ Session s = openSession();
+ s.createSQLQuery( "select id from Product2 where description like 'Kit%' order by id;" )
+ .setFirstResult( 2 ).setMaxResults( 2 ).list();
+ s.close();
+ }
+
+ @Test
+ public void testPaginationWithHQLProjection() {
+ Session session = openSession();
+ Transaction tx = session.beginTransaction();
+
+ for ( int i = 10; i < 20; i++ ) {
+ session.persist( new Product2( i, "Kit" + i ) );
+ }
+ session.flush();
+ session.clear();
+
+ List list = session.createQuery(
+ "select id, description as descr, (select max(id) from Product2) as maximum from Product2"
+ ).setFirstResult( 2 ).setMaxResults( 2 ).list();
+ assertEquals( 19, ( (Object[]) list.get( 1 ) )[2] );
+
+ list = session.createQuery( "select id, description, (select max(id) from Product2) from Product2 order by id" )
+ .setFirstResult( 2 ).setMaxResults( 2 ).list();
+ assertEquals( 2, list.size() );
+ assertArrayEquals( new Object[] {12, "Kit12", 19}, (Object[]) list.get( 0 ));
+ assertArrayEquals( new Object[] {13, "Kit13", 19}, (Object[]) list.get( 1 ));
+
+ tx.rollback();
+ session.close();
+ }
+
+ @Test
+ public void testPaginationWithHQL() {
+ Session session = openSession();
+ Transaction tx = session.beginTransaction();
+
+ for ( int i = 20; i < 30; i++ ) {
+ session.persist( new Product2( i, "Kit" + i ) );
+ }
+ session.flush();
+ session.clear();
+
+ List list = session.createQuery( "from Product2 order by id" ).setFirstResult( 3 ).setMaxResults( 2 ).list();
+ assertEquals( Arrays.asList( new Product2( 23, "Kit23" ), new Product2( 24, "Kit24" ) ), list );
+
+ tx.rollback();
+ session.close();
+ }
+
+ @Test
+ @TestForIssue(jiraKey = "HHH-7370")
+ public void testPaginationWithMaxOnly() {
+ Session session = openSession();
+ Transaction tx = session.beginTransaction();
+
+ for ( int i = 30; i < 40; i++ ) {
+ session.persist( new Product2( i, "Kit" + i ) );
+ }
+ session.flush();
+ session.clear();
+
+ List list = session.createQuery( "from Product2 order by id" ).setFirstResult( 0 ).setMaxResults( 2 ).list();
+ assertEquals( Arrays.asList( new Product2( 30, "Kit30" ), new Product2( 31, "Kit31" ) ), list );
+
+ list = session.createQuery( "select distinct p from Product2 p order by p.id" ).setMaxResults( 1 ).list();
+ assertEquals( Arrays.asList( new Product2( 30, "Kit30" ) ), list );
+
+ tx.rollback();
+ session.close();
+ }
+
+ @Test
+ @TestForIssue(jiraKey = "HHH-3961")
public void testLockNowaitSqlServer() throws Exception {
Session s = openSession();
s.beginTransaction();
@@ -189,5 +285,4 @@ public class SQLServerDialectTest extends BaseCoreFunctionalTestCase {
Product2.class
};
}
-
}