3 Star 12 Fork 5

tenmg / sql-paging

加入 Gitee
与超过 1200万 开发者一起发现、参与优秀开源项目,私有仓库也完全免费 :)
免费加入
克隆/下载
贡献代码
同步代码
取消
提示: 由于 Git 不支持空文件夾,创建文件夹后会生成空的 .keep 文件
Loading...
README
Apache-2.0

sql-paging

maven

介绍

sql-paging是一个SQL分页查询方言类库,它原来是Sqltool的智能分页组件,后剥离出来作为独立项目,以供更多组件集成其能力。通过调用相关API,可快速将一个普通SQL转换为一个特定数据库的计数(COUNT)SQL或分页查询SQL。sql-paging通过内置的SQL分析工具类分析实际调用的SQL,让方言生成最优的计数(COUNT)SQL或分页查询SQL。

数据库支持

数据库 支持版本 方言实现类
MySQL 1.0+ MySQLPagingDialect
Oracle 1.0+ OraclePagingDialect
PostgreSQL 1.0+ PostgreSQLPagingDialect
SQLServer 1.0+ SQLServerPagingDialect
SQLite 1.2.7+ SQLitePagingDialect

使用说明

以基于Maven项目为例

  1. pom.xml添加依赖,${sql-paging.version}为版本号,可定义属性或直接使用版本号替换
<!-- https://mvnrepository.com/artifact/cn.tenmg/sql-paging -->
<dependency>
    <groupId>cn.tenmg</groupId>
    <artifactId>sql-paging</artifactId>
    <version>${sql-paging.version}</version>
</dependency>
  1. 调用SQLPagingDialect.countSql方法获取计数SQL(以MySQL数据库为例)
String namedSql = "……";
sqlMetaData sqlMetaData = SQLUtils.getSQLMetaData(namedSql);
SQLPagingDialect dialect = MySQLPagingDialect.getInstance();
String countSql = dialect.countSql(namedSql, sqlMetaData);
……
  1. 调用SQLPagingDialect.pageSql方法获取分页查询SQL(以MySQL数据库为例)
……
try {
    String pageSql = dialect.pageSql(con, namedSql, params, sqlMetaData, 20, 2);
    ……
} catch (SQLException e) {
    // TODO Auto-generated catch block
    e.printStackTrace();
}
……

API详解

countSql

用于根据实际查询的SQL自动生成计数SQL,完成对总数的统计,结合页容量可计算出总页数。根据对源SQL的分析和智能决策,生成计数SQL会去除不必要的列或者排序子句(ORDER BY),且不会引入不必要子查询,以达到最优性能。例如如下SQL:

SELECT
  S.STAFF_ID,
  S.STAFF_NAME,
  S.DEPARTMENT_ID,
  S.POSITION,
  S.STATUS
FROM STAFF_INFO S
ORDER BY S.STAFF_ID

并不是简单包裹子查询实现计数:

SELECT
  COUNT(*)
FROM (
  SELECT
    S.STAFF_ID,
    S.STAFF_NAME,
    S.DEPARTMENT_ID,
    S.POSITION,
    S.STATUS
  FROM STAFF_INFO S
  ORDER BY S.STAFF_ID
) T

而是,不嵌套不必要的子查询,并去除不必要的排序子句:

SELECT
  COUNT(*)
FROM STAFF_INFO S

嗯,这的确是我们想要的样子。但如果情况复杂一点呢?比如,我们需要查询某段时间内用户的订单金额并按金额从大到小排序:

SELECT
  USER_ID,
  SUM(AMT) AMT
FROM ORDER_INFO O
WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
GROUP BY USER_ID
ORDER BY SUM(AMT) DESC

我们得到的是:

SELECT
  COUNT(*)
FROM (
  SELECT
    USER_ID,
    SUM(AMT) AMT
  FROM ORDER_INFO O
  WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
  GROUP BY USER_ID
) SQL_PAGING

干得漂亮!这完全是我们所期待的。但如果情况再复杂一点呢?比如这样,我们需要查询某段时间内订单金额前一百名的用户:

SELECT
  USER_ID, /*用户编号*/
  AMT      /*订单金额*/
FROM (
  SELECT
    USER_ID,
    SUM(AMT) AMT
  FROM ORDER_INFO O
  WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
  GROUP BY USER_ID
) T
ORDER BY AMT DESC
LIMIT 100

我们得到的是:

SELECT
  COUNT(*)
FROM (
  SELECT
    USER_ID, /*用户编号*/
    AMT      /*订单金额*/
  FROM (
    SELECT
      USER_ID,
      SUM(AMT) AMT
    FROM ORDER_INFO O
    WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
  ) T
  LIMIT 100
) SQL_PAGING

sql-paging没有误杀无辜者,除了去除 ORDER BY 子句之外,其他保留原样,保证了结果正确性的同时,提升了查询效率。

pageSql

用于根据实际查询的SQL生成分页查询SQL,它也不是简单地对源SQL包裹子查询,同样是按需智能决策。继续上述三个例子:

SELECT
  S.STAFF_ID,
  S.STAFF_NAME,
  S.DEPARTMENT_ID,
  S.POSITION,
  S.STATUS
FROM STAFF_INFO S
ORDER BY S.STAFF_ID

得到的分页查询SQL(以页容量为10,页码第2页为例):

1.1. MySQL

SELECT
  S.STAFF_ID,
  S.STAFF_NAME,
  S.DEPARTMENT_ID,
  S.POSITION,
  S.STATUS
FROM STAFF_INFO S
ORDER BY S.STAFF_ID
LIMIT 10,10

1.2. Oracle

SELECT
  STAFF_ID,
  STAFF_NAME,
  DEPARTMENT_ID,
  POSITION,
  STATUS
FROM (
  SELECT
    ROWNUM RN__,
    SQL_PAGING.*
  FROM (
    SELECT
      S.STAFF_ID,
      S.STAFF_NAME,
      S.DEPARTMENT_ID,
      S.POSITION,
      S.STATUS
    FROM STAFF_INFO S
    ORDER BY S.STAFF_ID
  ) SQL_PAGING
  WHERE RN__ <= 20
)
WHERE RN__ > 10

1.3. PostgresSQL

SELECT
  S.STAFF_ID,
  S.STAFF_NAME,
  S.DEPARTMENT_ID,
  S.POSITION,
  S.STATUS
FROM STAFF_INFO S
ORDER BY S.STAFF_ID
LIMIT 10 OFFSET 10
SELECT
  USER_ID,
  SUM(AMT) AMT
FROM ORDER_INFO O
WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
GROUP BY USER_ID
ORDER BY SUM(AMT) DESC

得到的分页查询SQL(以页容量为10,页码第2页为例):

2.1. MySQL:

SELECT
  USER_ID,
  SUM(AMT) AMT
FROM ORDER_INFO O
WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
GROUP BY USER_ID
ORDER BY SUM(AMT) DESC
LIMIT 10,10

2.2. Oracle

SELECT
  USER_ID,
  AMT
FROM (
  SELECT
    ROWNUM RN__,
    SQL_PAGING.*
  FROM (
    SELECT
      USER_ID,
      SUM(AMT) AMT
    FROM ORDER_INFO O
    WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
    GROUP BY USER_ID
    ORDER BY SUM(AMT) DESC
  ) SQL_PAGING
  WHERE RN__ <= 20
)
WHERE RN__ > 10

2.3. PostgresSQL

SELECT
  USER_ID,
  SUM(AMT) AMT
FROM ORDER_INFO O
WHERE O.CREATE_TIME >= :begin AND O.CREATE_TIME < :end
GROUP BY USER_ID
ORDER BY SUM(AMT) DESC
LIMIT 10 OFFSET 10

参与贡献

  1. Fork 本仓库
  2. 新建 Feat_xxx 分支
  3. 提交代码
  4. 新建 Pull Request

相关链接

DSL开源地址:https://gitee.com/tenmg/dsl

Apache License Version 2.0, January 2004 http://www.apache.org/licenses/ TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 1. Definitions. "License" shall mean the terms and conditions for use, reproduction, and distribution as defined by Sections 1 through 9 of this document. "Licensor" shall mean the copyright owner or entity authorized by the copyright owner that is granting the License. "Legal Entity" shall mean the union of the acting entity and all other entities that control, are controlled by, or are under common control with that entity. For the purposes of this definition, "control" means (i) the power, direct or indirect, to cause the direction or management of such entity, whether by contract or otherwise, or (ii) ownership of fifty percent (50%) or more of the outstanding shares, or (iii) beneficial ownership of such entity. "You" (or "Your") shall mean an individual or Legal Entity exercising permissions granted by this License. "Source" form shall mean the preferred form for making modifications, including but not limited to software source code, documentation source, and configuration files. "Object" form shall mean any form resulting from mechanical transformation or translation of a Source form, including but not limited to compiled object code, generated documentation, and conversions to other media types. "Work" shall mean the work of authorship, whether in Source or Object form, made available under the License, as indicated by a copyright notice that is included in or attached to the work (an example is provided in the Appendix below). "Derivative Works" shall mean any work, whether in Source or Object form, that is based on (or derived from) the Work and for which the editorial revisions, annotations, elaborations, or other modifications represent, as a whole, an original work of authorship. For the purposes of this License, Derivative Works shall not include works that remain separable from, or merely link (or bind by name) to the interfaces of, the Work and Derivative Works thereof. "Contribution" shall mean any work of authorship, including the original version of the Work and any modifications or additions to that Work or Derivative Works thereof, that is intentionally submitted to Licensor for inclusion in the Work by the copyright owner or by an individual or Legal Entity authorized to submit on behalf of the copyright owner. For the purposes of this definition, "submitted" means any form of electronic, verbal, or written communication sent to the Licensor or its representatives, including but not limited to communication on electronic mailing lists, source code control systems, and issue tracking systems that are managed by, or on behalf of, the Licensor for the purpose of discussing and improving the Work, but excluding communication that is conspicuously marked or otherwise designated in writing by the copyright owner as "Not a Contribution." "Contributor" shall mean Licensor and any individual or Legal Entity on behalf of whom a Contribution has been received by Licensor and subsequently incorporated within the Work. 2. Grant of Copyright License. Subject to the terms and conditions of this License, each Contributor hereby grants to You a perpetual, worldwide, non-exclusive, no-charge, royalty-free, irrevocable copyright license to reproduce, prepare Derivative Works of, publicly display, publicly perform, sublicense, and distribute the Work and such Derivative Works in Source or Object form. 3. Grant of Patent License. Subject to the terms and conditions of this License, each Contributor hereby grants to You a perpetual, worldwide, non-exclusive, no-charge, royalty-free, irrevocable (except as stated in this section) patent license to make, have made, use, offer to sell, sell, import, and otherwise transfer the Work, where such license applies only to those patent claims licensable by such Contributor that are necessarily infringed by their Contribution(s) alone or by combination of their Contribution(s) with the Work to which such Contribution(s) was submitted. If You institute patent litigation against any entity (including a cross-claim or counterclaim in a lawsuit) alleging that the Work or a Contribution incorporated within the Work constitutes direct or contributory patent infringement, then any patent licenses granted to You under this License for that Work shall terminate as of the date such litigation is filed. 4. Redistribution. You may reproduce and distribute copies of the Work or Derivative Works thereof in any medium, with or without modifications, and in Source or Object form, provided that You meet the following conditions: (a) You must give any other recipients of the Work or Derivative Works a copy of this License; and (b) You must cause any modified files to carry prominent notices stating that You changed the files; and (c) You must retain, in the Source form of any Derivative Works that You distribute, all copyright, patent, trademark, and attribution notices from the Source form of the Work, excluding those notices that do not pertain to any part of the Derivative Works; and (d) If the Work includes a "NOTICE" text file as part of its distribution, then any Derivative Works that You distribute must include a readable copy of the attribution notices contained within such NOTICE file, excluding those notices that do not pertain to any part of the Derivative Works, in at least one of the following places: within a NOTICE text file distributed as part of the Derivative Works; within the Source form or documentation, if provided along with the Derivative Works; or, within a display generated by the Derivative Works, if and wherever such third-party notices normally appear. The contents of the NOTICE file are for informational purposes only and do not modify the License. You may add Your own attribution notices within Derivative Works that You distribute, alongside or as an addendum to the NOTICE text from the Work, provided that such additional attribution notices cannot be construed as modifying the License. You may add Your own copyright statement to Your modifications and may provide additional or different license terms and conditions for use, reproduction, or distribution of Your modifications, or for any such Derivative Works as a whole, provided Your use, reproduction, and distribution of the Work otherwise complies with the conditions stated in this License. 5. Submission of Contributions. Unless You explicitly state otherwise, any Contribution intentionally submitted for inclusion in the Work by You to the Licensor shall be under the terms and conditions of this License, without any additional terms or conditions. Notwithstanding the above, nothing herein shall supersede or modify the terms of any separate license agreement you may have executed with Licensor regarding such Contributions. 6. Trademarks. This License does not grant permission to use the trade names, trademarks, service marks, or product names of the Licensor, except as required for reasonable and customary use in describing the origin of the Work and reproducing the content of the NOTICE file. 7. Disclaimer of Warranty. Unless required by applicable law or agreed to in writing, Licensor provides the Work (and each Contributor provides its Contributions) on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied, including, without limitation, any warranties or conditions of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A PARTICULAR PURPOSE. You are solely responsible for determining the appropriateness of using or redistributing the Work and assume any risks associated with Your exercise of permissions under this License. 8. Limitation of Liability. In no event and under no legal theory, whether in tort (including negligence), contract, or otherwise, unless required by applicable law (such as deliberate and grossly negligent acts) or agreed to in writing, shall any Contributor be liable to You for damages, including any direct, indirect, special, incidental, or consequential damages of any character arising as a result of this License or out of the use or inability to use the Work (including but not limited to damages for loss of goodwill, work stoppage, computer failure or malfunction, or any and all other commercial damages or losses), even if such Contributor has been advised of the possibility of such damages. 9. Accepting Warranty or Additional Liability. While redistributing the Work or Derivative Works thereof, You may choose to offer, and charge a fee for, acceptance of support, warranty, indemnity, or other liability obligations and/or rights consistent with this License. However, in accepting such obligations, You may act only on Your own behalf and on Your sole responsibility, not on behalf of any other Contributor, and only if You agree to indemnify, defend, and hold each Contributor harmless for any liability incurred by, or claims asserted against, such Contributor by reason of your accepting any such warranty or additional liability. END OF TERMS AND CONDITIONS APPENDIX: How to apply the Apache License to your work. To apply the Apache License to your work, attach the following boilerplate notice, with the fields enclosed by brackets "[]" replaced with your own identifying information. (Don't include the brackets!) The text should be enclosed in the appropriate comment syntax for the file format. We also recommend that a file or class name and description of purpose be included on the same "printed page" as the copyright notice for easier identification within third-party archives. Copyright [yyyy] [name of copyright owner] Licensed under the Apache License, Version 2.0 (the "License"); you may not use this file except in compliance with the License. You may obtain a copy of the License at http://www.apache.org/licenses/LICENSE-2.0 Unless required by applicable law or agreed to in writing, software distributed under the License is distributed on an "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. See the License for the specific language governing permissions and limitations under the License.

简介

SQL分页查询方言类库。通过调用相关API,可快速将一个普通SQL转换为一个特定数据库的计数(COUNT)SQL或分页查询SQL。 展开 收起
Java
Apache-2.0
取消

发行版 (18)

全部

贡献者

全部

近期动态

加载更多
不能加载更多了
Java
1
https://gitee.com/tenmg/sql-paging.git
git@gitee.com:tenmg/sql-paging.git
tenmg
sql-paging
sql-paging
master

搜索帮助