HHH-8916 - Allow CTE queries to be translated by SQL Server LimitHandler impl.

This commit is contained in:
Chris Cranford 2017-05-21 04:31:12 -04:00 committed by Vlad Mihalcea
parent 839433991f
commit ce3818afe8
3 changed files with 374 additions and 35 deletions

View File

@ -11,6 +11,7 @@ import java.sql.SQLException;
import java.util.ArrayList;
import java.util.LinkedList;
import java.util.List;
import java.util.Locale;
import java.util.regex.Matcher;
import java.util.regex.Pattern;
@ -42,8 +43,18 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
private static final Pattern ALIAS_PATTERN =
Pattern.compile( "(?![^\\[]*(\\]))\\S+\\s*(\\s(?i)as\\s)\\s*(\\S+)*\\s*$|(?![^\\[]*(\\]))\\s+(\\S+)$" );
// CTE pattern support
private static final String SPACE_NEWLINE_LINEFEED = "[\\s\\t\\n\\r]*";
private static final Pattern WITH_CTE = Pattern.compile( "(^" + SPACE_NEWLINE_LINEFEED + "WITH" + SPACE_NEWLINE_LINEFEED +")", Pattern.CASE_INSENSITIVE );
private static final Pattern WITH_EXPRESSION_NAME = Pattern.compile( "(^" + SPACE_NEWLINE_LINEFEED + "[a-zA-Z0-9]*" + SPACE_NEWLINE_LINEFEED +")", Pattern.CASE_INSENSITIVE );
private static final Pattern WITH_COLUMN_NAMES_START = Pattern.compile( "(^" + SPACE_NEWLINE_LINEFEED + "\\()", Pattern.CASE_INSENSITIVE );
private static final Pattern WITH_COLUMN_NAMES_END = Pattern.compile( "(\\))", Pattern.CASE_INSENSITIVE );
private static final Pattern WITH_AS = Pattern.compile( "(^" + SPACE_NEWLINE_LINEFEED + "AS" + SPACE_NEWLINE_LINEFEED +")", Pattern.CASE_INSENSITIVE );
private static final Pattern WITH_COMMA = Pattern.compile( "(^" + SPACE_NEWLINE_LINEFEED + ",)", Pattern.CASE_INSENSITIVE );
// Flag indicating whether TOP(?) expression has been added to the original query.
private boolean topAdded;
private boolean isCTE;
/**
* Constructs a SQLServer2005LimitHandler
@ -103,23 +114,26 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
sb.setLength( sb.length() - 1 );
}
if ( LimitHelper.hasFirstRow( selection ) ) {
final String selectClause = fillAliasInSelectClause( sb );
// checks the query buffer for CTE queries or simple SELECT statements
// returns the index where the injection should start.
final int offset = getStatementIndex( sb );
final int orderByIndex = shallowIndexOfPattern( sb, ORDER_BY_PATTERN, 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__ < ?" );
if ( !LimitHelper.hasFirstRow( selection ) ) {
addTopExpression( sb, offset );
}
else {
addTopExpression( sb );
final String selectClause = fillAliasInSelectClause( sb, offset );
if ( shallowIndexOfPattern( sb, ORDER_BY_PATTERN, offset ) > 0 ) {
// ORDER BY requires using TOP
addTopExpression( sb, offset );
}
encloseWithOuterQuery( sb, offset );
sb.insert( offset, !isCTE ? "WITH query AS (" : ", query AS (" );
sb.append( ") SELECT " ).append( selectClause ).append( " FROM query " );
sb.append( "WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?" );
}
return sb.toString();
@ -146,13 +160,14 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
* method returns {@literal *}.
*
* @param sb SQL query.
* @param offset the starting offset.
*
* @return List of aliases separated with comas or {@literal *}.
*/
protected String fillAliasInSelectClause(StringBuilder sb) {
protected String fillAliasInSelectClause(StringBuilder sb, int offset) {
final String separator = System.lineSeparator();
final List<String> aliases = new LinkedList<String>();
final int startPos = getSelectColumnsStartPosition( sb );
final int startPos = getSelectColumnsStartPosition( sb, offset );
int endPos = shallowIndexOfPattern( sb, FROM_PATTERN, startPos );
int nextComa = startPos;
@ -213,10 +228,11 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
* Get the start position for where the column list begins.
*
* @param sb the string builder sql.
* @param offset the starting offset.
* @return the start position where the column list begins.
*/
private int getSelectColumnsStartPosition(StringBuilder sb) {
final int startPos = getSelectStartPosition( sb );
private int getSelectColumnsStartPosition(StringBuilder sb, int offset) {
final int startPos = getSelectStartPosition( sb, offset );
// adjustment for 'select distinct ' and 'select '.
final String sql = sb.toString().substring( startPos ).toLowerCase();
if ( sql.startsWith( SELECT_DISTINCT_SPACE ) ) {
@ -232,10 +248,11 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
* Get the select start position.
*
* @param sb the string builder sql.
* @param offset the starting offset in buffer.
* @return the position where {@code select} is found.
*/
private int getSelectStartPosition(StringBuilder sb) {
return shallowIndexOfPattern( sb, SELECT_PATTERN, 0 );
private int getSelectStartPosition(StringBuilder sb, int offset) {
return shallowIndexOfPattern( sb, SELECT_PATTERN, offset );
}
/**
@ -284,9 +301,10 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
* Encloses original SQL statement with outer query that provides {@literal __hibernate_row_nr__} column.
*
* @param sql SQL query.
* @param offset SQL query offset.
*/
protected void encloseWithOuterQuery(StringBuilder sql) {
sql.insert( 0, "SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " );
protected void encloseWithOuterQuery(StringBuilder sql, int offset) {
sql.insert( offset, "SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( " );
sql.append( " ) inner_query " );
}
@ -295,11 +313,12 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
* {@link #bindLimitParametersAtStartOfQuery(RowSelection, PreparedStatement, int)} method.
*
* @param sql SQL query.
* @param offset the offset where top expression pattern matching should begin.
*/
protected void addTopExpression(StringBuilder sql) {
protected void addTopExpression(StringBuilder sql, int offset) {
// We should use either of these which come first (SELECT or SELECT DISTINCT).
final int selectPos = shallowIndexOfPattern( sql, SELECT_PATTERN, 0 );
final int selectDistinctPos = shallowIndexOfPattern( sql, SELECT_DISTINCT_PATTERN, 0 );
final int selectPos = shallowIndexOfPattern( sql, SELECT_PATTERN, offset );
final int selectDistinctPos = shallowIndexOfPattern( sql, SELECT_DISTINCT_PATTERN, offset );
if ( selectPos == selectDistinctPos ) {
// Place TOP after SELECT DISTINCT
sql.insert( selectDistinctPos + SELECT_DISTINCT.length(), " TOP(?)" );
@ -449,4 +468,146 @@ public class SQLServer2005LimitHandler extends AbstractLimitHandler {
return position >= start && position <= end;
}
}
/**
* Get the starting point for the limit handler to begin injecting and transforming the SQL.
* For non-CTE queries, this is offset 0. For CTE queries, this will be where the CTE's
* SELECT clause begins (skipping all query definitions, column definitions and expressions).
*
* This method also sets {@code isCTE} if the query is parsed as a CTE query.
*
* @param sql The sql buffer.
* @return the index where to begin parsing.
*/
private int getStatementIndex(StringBuilder sql) {
final Matcher matcher = WITH_CTE.matcher( sql.toString() );
if ( matcher.find() && matcher.groupCount() > 0 ) {
isCTE = true;
return locateQueryInCTEStatement( sql, matcher.end() );
}
return 0;
}
/**
* Steps through the SQL buffer from the specified offset and performs a series of pattern matches.
* The method locates where the CTE SELECT clause begins and returns that offset from the SQL buffer.
*
* @param sql The sql buffer.
* @param offset The offset to begin pattern matching.
*
* @return the offset where the CTE SELECT clause begins.
* @throws IllegalArgumentException if the parse of the CTE query fails.
*/
private int locateQueryInCTEStatement(StringBuilder sql, int offset) {
while ( true ) {
Matcher matcher = WITH_EXPRESSION_NAME.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
offset += matcher.end();
matcher = WITH_COLUMN_NAMES_START.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
offset += matcher.end();
matcher = WITH_COLUMN_NAMES_END.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
offset += matcher.end();
offset += advanceOverCTEInnerQuery( sql, offset );
matcher = WITH_COMMA.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
// another CTE fragment exists, re-start parse of CTE
offset += matcher.end();
}
else {
// last CTE fragment, we're at the start of the SQL.
return offset;
}
}
else {
throw new IllegalArgumentException(
String.format(
Locale.ROOT,
"Failed to parse CTE expression columns at offset %d, SQL [%s]",
offset,
sql.toString()
)
);
}
}
else {
matcher = WITH_AS.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
offset += matcher.end();
offset += advanceOverCTEInnerQuery( sql, offset );
matcher = WITH_COMMA.matcher( sql.substring( offset ) );
if ( matcher.find() && matcher.groupCount() > 0 ) {
// another CTE fragment exists, re-start parse of CTE
offset += matcher.end();
}
else {
// last CTE fragment, we're at the start of the SQL.
return offset;
}
}
else {
throw new IllegalArgumentException(
String.format(
Locale.ROOT,
"Failed to locate AS keyword in CTE query at offset %d, SQL [%s]",
offset,
sql.toString()
)
);
}
}
}
else {
throw new IllegalArgumentException(
String.format(
Locale.ROOT,
"Failed to locate CTE expression name at offset %d, SQL [%s]",
offset,
sql.toString()
)
);
}
}
}
/**
* Advances over the CTE inner query that is contained inside matching '(' and ')'.
*
* @param sql The sql buffer.
* @param offset The offset where to begin advancing the position from.
* @return the position immediately after the CTE inner query plus 1.
*
* @throws IllegalArgumentException if the matching parenthesis aren't detected at the end of the parse.
*/
private int advanceOverCTEInnerQuery(StringBuilder sql, int offset) {
int brackets = 0;
int index = offset;
boolean inString = false;
for ( ; index < sql.length(); ++index ) {
if ( sql.charAt( index ) == '\'' ) {
inString = true;
}
else if ( sql.charAt( index ) == '\'' && inString ) {
inString = false;
}
else if ( sql.charAt( index ) == '(' && !inString ) {
brackets++;
}
else if ( sql.charAt( index ) == ')' && !inString ) {
brackets--;
if ( brackets == 0 ) {
break;
}
}
}
if ( brackets > 0 ) {
throw new IllegalArgumentException(
"Failed to parse the CTE query inner query because closing ')' was not found."
);
}
return index - offset + 1;
}
}

View File

@ -409,6 +409,92 @@ public class SQLServer2005DialectTestCase extends BaseUnitTestCase {
);
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testGetLimitStringUsingCTEQueryNoOffset() {
RowSelection selection = toRowSelection( 0, 5 );
// test top-based CTE with single CTE query definition with no odd formatting
final String query1 = "WITH a (c1, c2) AS (SELECT c1, c2 FROM t) SELECT c1, c2 FROM a";
assertEquals(
"WITH a (c1, c2) AS (SELECT c1, c2 FROM t) SELECT TOP(?) c1, c2 FROM a",
dialect.getLimitHandler().processSql( query1, selection )
);
// test top-based CTE with single CTE query definition and various tab, newline spaces
final String query2 = " \n\tWITH a (c1\n\t,c2)\t\nAS (SELECT\n\tc1,c2 FROM t)\t\nSELECT c1, c2 FROM a";
assertEquals(
" \n\tWITH a (c1\n\t,c2)\t\nAS (SELECT\n\tc1,c2 FROM t)\t\nSELECT TOP(?) c1, c2 FROM a",
dialect.getLimitHandler().processSql( query2, selection )
);
// test top-based CTE with multiple CTE query definitions with no odd formatting
final String query3 = "WITH a (c1, c2) AS (SELECT c1, c2 FROM t1), b (b1, b2) AS (SELECT b1, b2 FROM t2) " +
"SELECT c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1";
assertEquals(
"WITH a (c1, c2) AS (SELECT c1, c2 FROM t1), b (b1, b2) AS (SELECT b1, b2 FROM t2) " +
"SELECT TOP(?) c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1",
dialect.getLimitHandler().processSql( query3, selection )
);
// test top-based CTE with multiple CTE query definitions and various tab, newline spaces
final String query4 = " \n\r\tWITH a (c1, c2) AS\n\r (SELECT c1, c2 FROM t1)\n\r, b (b1, b2)\tAS\t" +
"(SELECT b1, b2 FROM t2) SELECT c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1";
assertEquals(
" \n\r\tWITH a (c1, c2) AS\n\r (SELECT c1, c2 FROM t1)\n\r, b (b1, b2)\tAS\t(SELECT b1, b2 FROM t2)" +
" SELECT TOP(?) c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1",
dialect.getLimitHandler().processSql( query4, selection )
);
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testGetLimitStringUsingCTEQueryWithOffset() {
RowSelection selection = toRowSelection( 1, 5 );
// test non-top based CTE with single CTE query definition with no odd formatting
final String query1 = "WITH a (c1, c2) AS (SELECT c1, c2 FROM t) SELECT c1, c2 FROM a";
assertEquals(
"WITH a (c1, c2) AS (SELECT c1, c2 FROM t), query AS (SELECT inner_query.*, ROW_NUMBER() OVER " +
"(ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( SELECT c1 as page0_, c2 as page1_ " +
"FROM a ) inner_query ) SELECT page0_, page1_ FROM query WHERE __hibernate_row_nr__ >= ? " +
"AND __hibernate_row_nr__ < ?",
dialect.getLimitHandler().processSql( query1, selection )
);
// test non-top based CTE with single CTE query definition and various tab, newline spaces
final String query2 = " \n\tWITH a (c1\n\t,c2)\t\nAS (SELECT\n\tc1,c2 FROM t)\t\nSELECT c1, c2 FROM a";
assertEquals(
" \n\tWITH a (c1\n\t,c2)\t\nAS (SELECT\n\tc1,c2 FROM t), query AS (SELECT inner_query.*, ROW_NUMBER()" +
" OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( \t\nSELECT c1 as page0_, c2 " +
"as page1_ FROM a ) inner_query ) SELECT page0_, page1_ FROM query WHERE __hibernate_row_nr__ >= " +
"? AND __hibernate_row_nr__ < ?",
dialect.getLimitHandler().processSql( query2, selection )
);
// test non-top based CTE with multiple CTE query definitions with no odd formatting
final String query3 = "WITH a (c1, c2) AS (SELECT c1, c2 FROM t1), b (b1, b2) AS (SELECT b1, b2 FROM t2) " +
" SELECT c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1";
assertEquals(
"WITH a (c1, c2) AS (SELECT c1, c2 FROM t1), b (b1, b2) AS (SELECT b1, b2 FROM t2), query AS (" +
"SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM (" +
" SELECT c1 as page0_, c2 as page1_, b1 as page2_, b2 as page3_ FROM t1, t2 WHERE t1.c1 = t2.b1 ) inner_query )" +
" SELECT page0_, page1_, page2_, page3_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
dialect.getLimitHandler().processSql( query3, selection )
);
// test top-based CTE with multiple CTE query definitions and various tab, newline spaces
final String query4 = " \n\r\tWITH a (c1, c2) AS\n\r (SELECT c1, c2 FROM t1)\n\r, b (b1, b2)\tAS\t(SELECT b1, " +
"b2 FROM t2) SELECT c1, c2, b1, b2 FROM t1, t2 WHERE t1.c1 = t2.b1";
assertEquals(
" \n\r\tWITH a (c1, c2) AS\n\r (SELECT c1, c2 FROM t1)\n\r, b (b1, b2)\tAS\t(SELECT b1, b2 FROM t2), query AS (" +
"SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM (" +
" SELECT c1 as page0_, c2 as page1_, b1 as page2_, b2 as page3_ FROM t1, t2 WHERE t1.c1 = t2.b1 ) inner_query )" +
" SELECT page0_, page1_, page2_, page3_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?",
dialect.getLimitHandler().processSql( query4, selection )
);
}
@Test
@TestForIssue(jiraKey = "HHH-9635")
public void testAppendLockHintReadPastLocking() {

View File

@ -6,16 +6,11 @@
*/
package org.hibernate.test.dialect.functional;
import java.sql.Connection;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.Arrays;
import java.util.Collections;
import java.util.List;
import java.util.concurrent.ExecutorService;
import java.util.concurrent.Executors;
import java.util.concurrent.TimeUnit;
import javax.persistence.Entity;
import javax.persistence.Id;
@ -28,15 +23,12 @@ import org.hibernate.cfg.Configuration;
import org.hibernate.criterion.Order;
import org.hibernate.criterion.Projections;
import org.hibernate.dialect.SQLServer2005Dialect;
import org.hibernate.engine.spi.SessionImplementor;
import org.hibernate.exception.LockTimeoutException;
import org.hibernate.jdbc.ReturningWork;
import org.junit.Test;
import org.hibernate.testing.RequiresDialect;
import org.hibernate.testing.TestForIssue;
import org.hibernate.testing.junit4.BaseCoreFunctionalTestCase;
import org.junit.Ignore;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInHibernate;
import static org.junit.Assert.assertArrayEquals;
@ -58,6 +50,106 @@ public class SQLServerDialectTest extends BaseCoreFunctionalTestCase {
return configuration;
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testPaginationWithCTEQueryNoOffset() {
// This used to throw SQLServerException: Incorrect syntax near 'SEL'
doInHibernate( this::sessionFactory, session -> {
for ( int i = 0; i < 20; ++i ) {
session.persist( new Product2( i, "Product" + i ) );
}
session.flush();
session.clear();
List results = session
.createNativeQuery( "WITH a AS (SELECT description FROM Product2) SELECT description FROM a" )
.setMaxResults( 10 )
.getResultList();
assertEquals( 10, results.size() );
assertEquals( String.class, results.get( 0 ).getClass() );
} );
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testPaginationWithCTEQueryNoOffsetNewLine() {
// This used to throw SQLServerException: Incorrect syntax near 'SEL'
doInHibernate( this::sessionFactory, session -> {
for ( int i = 0; i < 20; ++i ) {
session.persist( new Product2( i, "Product" + i ) );
}
session.flush();
session.clear();
List results = session
.createNativeQuery(
"WITH a AS (\n" +
"\tSELECT description \n" +
"\tFROM Product2\n" +
") \n" +
"SELECT description FROM a" )
.setMaxResults( 10 )
.getResultList();
assertEquals( 10, results.size() );
assertEquals( String.class, results.get( 0 ).getClass() );
} );
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testPaginationWithCTEQueryWithOffsetAndOrderBy() {
// This used to throw an StringIndexOutOfBoundsException
doInHibernate( this::sessionFactory, session -> {
for ( int i = 0; i < 20; ++i ) {
session.persist( new Product2( i, "Product" + i ) );
}
session.flush();
session.clear();
List results = session
.createNativeQuery( "WITH a AS (SELECT id, description FROM Product2) SELECT id, description FROM a ORDER BY id DESC" )
.setFirstResult( 5 )
.setMaxResults( 10 )
.getResultList();
assertEquals( 10, results.size() );
final Object[] row = (Object[]) results.get( 0 );
assertEquals( 2, row.length );
assertEquals( Integer.class, row[ 0 ].getClass() );
assertEquals( String.class, row[ 1 ].getClass() );
assertEquals( 14, row[0] );
assertEquals( "Product14", row[1] );
} );
}
@Test
@TestForIssue(jiraKey = "HHH-8916")
public void testPaginationWithCTEQueryWithOffset() {
// This used to throw an StringIndexOutOfBoundsException
doInHibernate( this::sessionFactory, session -> {
for ( int i = 0; i < 20; ++i ) {
session.persist( new Product2( i, "Product" + i ) );
}
session.flush();
session.clear();
List results = session
.createNativeQuery( "WITH a AS (SELECT id, description FROM Product2) SELECT id, description FROM a" )
.setFirstResult( 5 )
.setMaxResults( 10 )
.getResultList();
assertEquals( 10, results.size() );
final Object[] row = (Object[]) results.get( 0 );
assertEquals( 2, row.length );
assertEquals( Integer.class, row[ 0 ].getClass() );
assertEquals( String.class, row[ 1 ].getClass() );
} );
}
@Test
@TestForIssue(jiraKey = "HHH-7369")
public void testPaginationWithScalarQuery() throws Exception {