Skip to content

Commit

Permalink
SQLServer2005分页优化.
Browse files Browse the repository at this point in the history
  • Loading branch information
nieqiurong committed Apr 27, 2024
1 parent 7847987 commit d5abb8d
Show file tree
Hide file tree
Showing 2 changed files with 39 additions and 10 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -30,15 +30,17 @@
*/
public class SQLServer2005Dialect implements IDialect {

private static final Pattern pattern = Pattern.compile("\\((.)*order by(.)*\\)");
private static final Pattern ORDER_BY_PATTERN = Pattern.compile("\\((.)*order by(.)*\\)");

private static final Pattern SELECT_PATTERN = Pattern.compile("(?i)select\\s+(distinct\\s+)?");

public String getOrderByPart(String sql) {
String order_by = "order by";
int lastIndex = sql.toLowerCase().lastIndexOf(order_by);
if (lastIndex == -1) {
return StringPool.EMPTY;
}
Matcher matcher = pattern.matcher(sql);
Matcher matcher = ORDER_BY_PATTERN.matcher(sql);
if (!matcher.find()) {
return sql.substring(lastIndex);
}
Expand All @@ -51,20 +53,16 @@ public DialectModel buildPaginationSql(String originalSql, long offset, long lim
StringBuilder pagingBuilder = new StringBuilder();
String orderby = getOrderByPart(originalSql);
String distinctStr = StringPool.EMPTY;

String loweredString = originalSql.toLowerCase();
String sqlPartString = originalSql;
String trimStr = loweredString.trim();
if (trimStr.startsWith("select")) {
int index = loweredString.indexOf("select") + 6;
if (trimStr.startsWith("select distinct")) {
Matcher matcher = SELECT_PATTERN.matcher(originalSql);
if (matcher.find()) {
int index = matcher.end() - 1;
if (matcher.group().toLowerCase().contains("distinct")) {
distinctStr = "DISTINCT ";
index = loweredString.indexOf("select distinct") + 15;
}
sqlPartString = sqlPartString.substring(index);
}
pagingBuilder.append(sqlPartString);

// if no ORDER BY is specified use fake ORDER BY field to avoid errors
if (StringUtils.isBlank(orderby)) {
orderby = "ORDER BY CURRENT_TIMESTAMP";
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,37 @@ void test() {
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" select *,(select 1) from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("select distinct *,(select 1) from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT DISTINCT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" select distinct *,(select 1) from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT DISTINCT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("select *,(select 1) from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" select *,(select 1) from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(select 1) from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("select * from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, * from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" select * from test", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, * from test) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("SELECT DISTINCT *,(SELECT 1) FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT DISTINCT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(SELECT 1) FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" SELECT DISTINCT *,(SELECT 1) FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT DISTINCT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(SELECT 1) FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("SELECT *,(SELECT 1) FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(SELECT 1) FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" SELECT *,(SELECT 1) FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, *,(SELECT 1) FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql("SELECT * FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, * FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");
Assertions.assertEquals(sqlServer2005Dialect.buildPaginationSql(" SELECT * FROM TEST", 1, 10).getDialectSql(),
"WITH selectTemp AS (SELECT TOP 100 PERCENT ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __row_number__, * FROM TEST) SELECT * FROM selectTemp WHERE __row_number__ BETWEEN 2 AND 11 ORDER BY __row_number__");

}

}

0 comments on commit d5abb8d

Please sign in to comment.