mirror of
https://gitee.com/mybatis-flex/mybatis-flex.git
synced 2025-12-07 00:58:24 +08:00
!480 修正 [Bug]: SQL SERVER Limit问题
Merge pull request !480 from macy0122/main
This commit is contained in:
commit
ae5ca676e2
@ -15,10 +15,7 @@
|
|||||||
*/
|
*/
|
||||||
package com.mybatisflex.core.dialect;
|
package com.mybatisflex.core.dialect;
|
||||||
|
|
||||||
import com.mybatisflex.core.query.CPI;
|
import com.mybatisflex.core.query.*;
|
||||||
import com.mybatisflex.core.query.QueryOrderBy;
|
|
||||||
import com.mybatisflex.core.query.QueryTable;
|
|
||||||
import com.mybatisflex.core.query.QueryWrapper;
|
|
||||||
import com.mybatisflex.core.util.CollectionUtil;
|
import com.mybatisflex.core.util.CollectionUtil;
|
||||||
|
|
||||||
import java.util.List;
|
import java.util.List;
|
||||||
@ -54,7 +51,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* Postgresql 的处理器
|
* Postgresql 的处理器
|
||||||
* 适合 {@link DbType#POSTGRE_SQL,DbType#SQLITE,DbType#H2,DbType#HSQL,DbType#KINGBASE_ES,DbType#PHOENIX}
|
* 适合 {@link DbType#POSTGRE_SQL,DbType#SQLITE,DbType#H2,DbType#HSQL,DbType#KINGBASE_ES,DbType#PHOENIX}
|
||||||
@ -69,7 +65,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* derby 的处理器
|
* derby 的处理器
|
||||||
* 适合 {@link DbType#DERBY,DbType#ORACLE_12C,DbType#SQLSERVER ,DbType#POSTGRE_SQL}
|
* 适合 {@link DbType#DERBY,DbType#ORACLE_12C,DbType#SQLSERVER ,DbType#POSTGRE_SQL}
|
||||||
@ -83,7 +78,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* derby 的处理器
|
* derby 的处理器
|
||||||
* 适合 {@link DbType#DERBY,DbType#ORACLE_12C,DbType#SQLSERVER ,DbType#POSTGRE_SQL}
|
* 适合 {@link DbType#DERBY,DbType#ORACLE_12C,DbType#SQLSERVER ,DbType#POSTGRE_SQL}
|
||||||
@ -102,8 +96,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* SqlServer 2005 limit 处理器
|
* SqlServer 2005 limit 处理器
|
||||||
*/
|
*/
|
||||||
@ -120,6 +112,21 @@ public interface LimitOffsetProcessor {
|
|||||||
String originalSQL = sql.toString();
|
String originalSQL = sql.toString();
|
||||||
String orderByString;
|
String orderByString;
|
||||||
List<QueryOrderBy> orderBys = CPI.getOrderBys(queryWrapper);
|
List<QueryOrderBy> orderBys = CPI.getOrderBys(queryWrapper);
|
||||||
|
//with 查询根据查询列返回,去除__rn列
|
||||||
|
List<QueryColumn> columnList = CPI.getSelectColumns(queryWrapper);
|
||||||
|
String selectColumns = ASTERISK;
|
||||||
|
StringBuilder selectColumnsBuilder = new StringBuilder();
|
||||||
|
if (columnList != null && !columnList.isEmpty()) {
|
||||||
|
columnList.forEach(column -> {
|
||||||
|
String alias = column.getAlias();
|
||||||
|
if (alias != null) {
|
||||||
|
selectColumnsBuilder.append(alias).append(DELIMITER);
|
||||||
|
} else {
|
||||||
|
selectColumnsBuilder.append(column.getName()).append(DELIMITER);
|
||||||
|
}
|
||||||
|
});
|
||||||
|
selectColumns = selectColumnsBuilder.deleteCharAt(selectColumnsBuilder.length() - 2).toString();
|
||||||
|
}
|
||||||
if (orderBys == null || orderBys.isEmpty()) {
|
if (orderBys == null || orderBys.isEmpty()) {
|
||||||
orderByString = "ORDER BY CURRENT_TIMESTAMP";
|
orderByString = "ORDER BY CURRENT_TIMESTAMP";
|
||||||
} else {
|
} else {
|
||||||
@ -137,16 +144,20 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
|
|
||||||
StringBuilder newSql = new StringBuilder("WITH temp_datas AS(");
|
StringBuilder newSql = new StringBuilder("WITH temp_datas AS(");
|
||||||
newSql.append("SELECT ROW_NUMBER() OVER (").append(orderByString).append(") as __rn,").append(originalSQL.substring(6));
|
newSql.append("SELECT ROW_NUMBER() OVER (")
|
||||||
|
.append(orderByString)
|
||||||
|
.append(") as __rn,")
|
||||||
|
.append(originalSQL.substring(6));
|
||||||
newSql.append(")");
|
newSql.append(")");
|
||||||
newSql.append(" SELECT * FROM temp_datas WHERE __rn BETWEEN ").append(limitOffset + 1).append(" AND ").append(limitOffset + limitRows);
|
newSql.append(" SELECT ").append(selectColumns).append(" FROM temp_datas WHERE __rn BETWEEN ")
|
||||||
|
.append(limitOffset + 1)
|
||||||
|
.append(" AND ")
|
||||||
|
.append(limitOffset + limitRows);
|
||||||
newSql.append(" ORDER BY __rn");
|
newSql.append(" ORDER BY __rn");
|
||||||
return newSql;
|
return newSql;
|
||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* Informix 的处理器
|
* Informix 的处理器
|
||||||
* 适合 {@link DbType#INFORMIX}
|
* 适合 {@link DbType#INFORMIX}
|
||||||
@ -161,8 +172,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
|
|
||||||
/**
|
/**
|
||||||
*
|
*
|
||||||
* SINODB 的处理器
|
* SINODB 的处理器
|
||||||
@ -177,7 +186,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* Firebird 的处理器
|
* Firebird 的处理器
|
||||||
* 适合 {@link DbType#FIREBIRD}
|
* 适合 {@link DbType#FIREBIRD}
|
||||||
@ -191,7 +199,6 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* Oracle11g及以下数据库的处理器
|
* Oracle11g及以下数据库的处理器
|
||||||
* 适合 {@link DbType#ORACLE,DbType#DM,DbType#GAUSS}
|
* 适合 {@link DbType#ORACLE,DbType#DM,DbType#GAUSS}
|
||||||
@ -203,12 +210,14 @@ public interface LimitOffsetProcessor {
|
|||||||
}
|
}
|
||||||
StringBuilder newSql = new StringBuilder("SELECT * FROM (SELECT TEMP_DATAS.*, ROWNUM RN FROM (");
|
StringBuilder newSql = new StringBuilder("SELECT * FROM (SELECT TEMP_DATAS.*, ROWNUM RN FROM (");
|
||||||
newSql.append(sql);
|
newSql.append(sql);
|
||||||
newSql.append(") TEMP_DATAS WHERE ROWNUM <= ").append(limitOffset + limitRows).append(") WHERE RN > ").append(limitOffset);
|
newSql.append(") TEMP_DATAS WHERE ROWNUM <= ")
|
||||||
|
.append(limitOffset + limitRows)
|
||||||
|
.append(") WHERE RN > ")
|
||||||
|
.append(limitOffset);
|
||||||
return newSql;
|
return newSql;
|
||||||
}
|
}
|
||||||
return sql;
|
return sql;
|
||||||
};
|
};
|
||||||
|
|
||||||
/**
|
/**
|
||||||
* Sybase 处理器
|
* Sybase 处理器
|
||||||
* 适合 {@link DbType#SYBASE}
|
* 适合 {@link DbType#SYBASE}
|
||||||
|
|||||||
@ -69,6 +69,24 @@ public class SqlServer2005DialectTester {
|
|||||||
sql);
|
sql);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
@Test
|
||||||
|
public void testSelectSqlSqlserver2005With() {
|
||||||
|
QueryWrapper query = new QueryWrapper().select(ACCOUNT.ID.as("user_id"), ACCOUNT.AGE)
|
||||||
|
.from("TEST.dbo.tb_account")
|
||||||
|
.where(ACCOUNT.ID.in("100", "200"))
|
||||||
|
.and(ACCOUNT.SEX.eq(1))
|
||||||
|
.orderBy(ACCOUNT.ID.desc())
|
||||||
|
.limit(0, 10);
|
||||||
|
|
||||||
|
IDialect dialect = new Sqlserver2005DialectImpl(KeywordWrap.SQUARE_BRACKETS,
|
||||||
|
LimitOffsetProcessor.SQLSERVER_2005);
|
||||||
|
String sql = dialect.forSelectByQuery(query);
|
||||||
|
System.out.println(sql);
|
||||||
|
Assert.assertEquals(
|
||||||
|
"WITH temp_datas AS(SELECT ROW_NUMBER() OVER ( ORDER BY [tb_account].[id] DESC) as __rn, [tb_account].[id] AS [user_id], [tb_account].[age] FROM [TEST].[dbo].[tb_account] WHERE [tb_account].[id] IN (?, ?) AND [tb_account].[sex] = ?) SELECT user_id, age FROM temp_datas WHERE __rn BETWEEN 1 AND 10 ORDER BY __rn",
|
||||||
|
sql);
|
||||||
|
}
|
||||||
|
|
||||||
@Test
|
@Test
|
||||||
public void testSelectSqlSqlserver() {
|
public void testSelectSqlSqlserver() {
|
||||||
QueryWrapper query = new QueryWrapper().select()
|
QueryWrapper query = new QueryWrapper().select()
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user