Modified the SQLServerDialect in order to replace the distinct keyword with a groub by clause

This commit is contained in:
Yoryos Valotasios 2010-11-04 23:38:17 +02:00
parent 55c822c56e
commit 74c9ec6bda
2 changed files with 79 additions and 19 deletions

View File

@ -38,7 +38,9 @@ import org.hibernate.type.StandardBasicTypes;
*/
public class SQLServerDialect extends AbstractTransactSQLDialect {
private static final String SELECT = "select";
private static final String SELECT_DISTINCT = "select distinct";
private static final String DISTINCT = "distinct";
public SQLServerDialect() {
registerColumnType( Types.VARBINARY, "image" );
registerColumnType( Types.VARBINARY, 8000, "varbinary($l)" );
@ -96,30 +98,19 @@ public class SQLServerDialect extends AbstractTransactSQLDialect {
.toString();
}
StringBuilder sb = new StringBuilder( querySqlString.trim() );
StringBuilder sb = new StringBuilder( querySqlString.trim().toLowerCase() );
String querySqlLowered = querySqlString.trim().toLowerCase();
int orderByIndex = querySqlLowered.toLowerCase().indexOf( "order by" );
String orderby = orderByIndex > 0 ? querySqlString.substring( orderByIndex ) : "ORDER BY CURRENT_TIMESTAMP";
int orderByIndex = sb.indexOf( "order by" );
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() );
}
// Find the end of the select statement
int selectIndex = querySqlLowered.trim().indexOf(SELECT_DISTINCT);
if (selectIndex != -1) {
selectIndex += SELECT_DISTINCT.length();
} else {
selectIndex = querySqlLowered.trim().indexOf(SELECT);
if (selectIndex != -1) {
selectIndex += SELECT.length();
}
}
replaceDistinctWithGroupBy( sb );
// Isert after the select statement the row_number() function:
sb.insert(selectIndex, " ROW_NUMBER() OVER (" + orderby + ") as __hibernate_row_nr__,");
insertRowNumberFunction(sb, orderby);
//Wrap the query within a with statement:
sb.insert(0, "WITH query AS (").append(") SELECT * FROM query ");
@ -128,6 +119,33 @@ public class SQLServerDialect extends AbstractTransactSQLDialect {
return sb.toString();
}
protected static void replaceDistinctWithGroupBy(StringBuilder sb) {
int distinctIndex = sb.indexOf( DISTINCT );
if (distinctIndex > 0) {
sb.delete(distinctIndex, distinctIndex + DISTINCT.length() + 1);
sb.append(" group by").append(getSelectFieldsWithoutAs(sb));
}
}
protected static CharSequence getSelectFieldsWithoutAs(StringBuilder sql) {
String select = sql.substring( sql.indexOf(SELECT) + SELECT.length(), sql.indexOf("from"));
// Strip the as clauses
return stripAsStatement(select);
}
protected static String stripAsStatement(String str) {
return str.replaceAll("\\sas[^,]+(,?)", "$1");
}
protected static void insertRowNumberFunction(StringBuilder sb, CharSequence orderby) {
// Find the end of the select statement
int selectEndIndex = sb.indexOf( SELECT ) + SELECT.length();
// Isert after the select statement the row_number() function:
sb.insert( selectEndIndex, " ROW_NUMBER() OVER (" + orderby + ") as __hibernate_row_nr__," );
}
/**
* Use <tt>insert table(...) values(...) select SCOPE_IDENTITY()</tt>

View File

@ -0,0 +1,42 @@
package org.hibernate.dialect;
import junit.framework.TestCase;
/**
* Unit test of the behavior of the SQLServerDialect utility methods
*
* @author Valotasion Yoryos
*
*/
public class SQLServerDialectTestCase extends TestCase {
public void testStripAsStatement() {
String input = "some_field1 as f1, some_fild2 as f2, _field3 as f3 ";
assertEquals( "some_field1, some_fild2, _field3", SQLServerDialect.stripAsStatement(input) );
}
public void testGetSelectFieldsWithoutAs() {
StringBuilder input = new StringBuilder( "select some_field1 as f12, some_fild2 as f879, _field3 as _f24674_3 from...." );
String output = SQLServerDialect.getSelectFieldsWithoutAs( input ).toString();
assertEquals( " some_field1, some_fild2, _field3", output );
}
public void testReplaceDistinctWithGroupBy() {
StringBuilder input = new StringBuilder( "select distinct f1, f2 as ff, f3 from table where f1 = 5" );
SQLServerDialect.replaceDistinctWithGroupBy( input );
assertEquals( "select f1, f2 as ff, f3 from table where f1 = 5 group by f1, f2, f3 ", input.toString() );
}
public void testGetLimitString() {
String input = "select distinct f1 as f53245 from table849752 order by f234, f67 desc";
SQLServerDialect sqlDialect = new SQLServerDialect();
assertEquals( "with query as (select row_number() over (order by f234, f67 desc) as __hibernate_row_nr__, f1 as f53245 from table849752 group by f1) select * from query where __hibernate_row_nr__ between 11 and 15", sqlDialect.getLimitString(input, 10, 15).toLowerCase() );
}
}