Java hibernate+存储过程分页实现

版权声明:转载原创文章请以超链接形式请注明原文章出处,尊重作者,尊重原创!


恰饭广告




环境:

GsonUtil.java https://www.idaobin.com/archives/2120.html

前端分页插件 https://www.idaobin.com/archives/1962.html

SQL server存储过程:

CREATE PROCEDURE sp_page
@strTable varchar(50), --表名
@strColumn varchar(50), --按该列来进行分页
@intColType int, --@strColumn列的类型,0-数字类型,1-字符类型,2-日期时间类型
@intOrder bit, --排序,0-顺序,1-倒序
@strColumnlist varchar(800), --要查询出的字段列表,*表示全部字段
@intPageSize int, --每页记录数
@intPageNum int, --指定页
@strWhere varchar(800), --查询条件
@intPageCount int OUTPUT --总页数
AS
DECLARE @sql nvarchar(4000) --用于构造SQL语句
DECLARE @where1 varchar(800) --构造条件语句
DECLARE @where2 varchar(800) --构造条件语句
IF @strWhere is null or rtrim(@strWhere)=''
-- 为了避免SQL关键字与字段、表名等连在一起,首先为传入的变量添加空格
BEGIN --没有查询条件
SET @where1=' WHERE '
SET @where2=' '
END
ELSE
BEGIN --有查询条件
SET @where1=' WHERE ('+@strWhere+') AND '
SET @where2=' WHERE ('+@strWhere+') '
END
set @strColumn = ' ' + @strColumn + ' '
set @strColumnlist = ' ' + @strColumnlist + ' '
--构造SQL语句,计算总页数。计算公式为 总页数 = Ceiling ( 记录个数 / 页大小 )
SET @sql='SELECT @intPageCount=CEILING((COUNT(*)+0.0)/'
+ CAST(@intPageSize AS varchar)
+ ') FROM ' + @strTable + @where2
--执行SQL语句,计算总页数,并将其放入@intPageCount变量中
EXEC sp_executesql @sql,N'@intPageCount int OUTPUT',@intPageCount OUTPUT
--将总页数放到查询返回记录集的第一个字段前,此语句可省略
SET @strColumnlist= @strColumnlist
IF @intOrder=0 --构造升序的SQL
SET @sql='SELECT TOP '+ CAST(@intPageSize AS varchar) + ' ' +
@strColumnlist +
' FROM ' + @strTable + @where1 +
@strColumn + '>(SELECT MAX('+@strColumn+') '+
' FROM (SELECT TOP '+ CAST(@intPageSize*(@intPageNum - 1) AS varchar) +
@strColumn + ' FROM '+ @strTable+@where2+'ORDER BY '+@strColumn+') t) ORDER BY '+ @strColumn
ELSE --构造降序的SQL
SET @sql='SELECT TOP '+ CAST(@intPageSize AS varchar) + ' ' +
@strColumnlist+
' FROM '+ @strTable + @where1 +
@strColumn + '<(SELECT MIN('+@strColumn+') '+
' FROM (SELECT TOP '+ CAST(@intPageSize*(@intPageNum - 1) AS varchar) +
@strColumn + ' FROM '+ @strTable+@where2+'ORDER BY '+@strColumn+' DESC) t) ORDER BY '+
@strColumn + ' DESC'
IF @intPageNum=1--第一页
SET @sql='SELECT TOP '+ CAST(@intPageSize AS varchar(10)) + ' ' + @strColumnlist + ' FROM '+@strTable+
@where2+' ORDER BY '+@strColumn + CASE @intOrder WHEN 0 THEN '' ELSE ' DESC'
END
--PRINT @sql
EXEC(@sql)
GO

java后台代码:

PAgetion.java(分页数据的实体类)

public class Pagetion {
	private int currentPage; //当前页
	private int pageSize; //每页展示
	private int pageCount; //总页数
	private String result; //每页数据
	public int getCurrentPage() {
		return currentPage;
	}
	public void setCurrentPage(int currentPage) {
		this.currentPage = currentPage;
	}
	public int getPageSize() {
		return pageSize;
	}
	public void setPageSize(int pageSize) {
		this.pageSize = pageSize;
	}
	public int getPageCount() {
		return pageCount;
	}
	public void setPageCount(int pageCount) {
		this.pageCount = pageCount;
	}
	public String getResult() {
		return result;
	}
	public void setResult(String result) {
		this.result = result;
	}
	
}

DoWork.java(hibernate5)

import java.sql.Connection;
import java.sql.SQLException;
import org.hibernate.jdbc.Work;
 
public class DoWork implements Work{
	//hibernate3.3以上且不用spring框架的情况下,Hibernate中session.connection()的替代方法
	private Connection connection;
	public void execute(Connection con) throws SQLException {
			connection=con;
	}
	public Connection getConnection() {
		return connection;
	}
}

HibernateUtil.java(hibernate分页帮助方法)

	public  Pagetion getPage(String produce, Object[] param) {
		ResultSet rs = null;
		Pagetion page=new Pagetion();
		String str="";
		for(int i=0;i<param.length;i++){
			str+="?,";
		}
		str="("+str.substring(0,str.length() - 1)+")}";
		
		Session session = HibernateSessionFactory.getSession();
		DoWork work = new DoWork();
		session.doWork(work);
		Connection con = work.getConnection();
//		Connection con = session.connection(); //hibernate3.3以下使用该方法
		produce = "{Call " + produce + str;
		CallableStatement call=null;
		try{
			call = con.prepareCall(produce);
			for (int i = 0; i < param.length; i++) {
				call.setObject(i + 1, param[i]);
			}
			call.registerOutParameter(9, Types.INTEGER); //输出参数
			rs = call.executeQuery();
			
			page.setResult(GsonUtil.resultSetToJson(rs));
			page.setPageCount(call.getInt(9));
		}
		catch(Exception e){
			e.printStackTrace();
			if (session != null)
				session.close();
			return null;
		}
		session.close();
		page.setPageSize((int) param[5]);
		page.setCurrentPage((int) param[6]);
		
		return page;

	}
	
	
	/**
	 * 存储过程分页查询
	 * @param produce String 存储过程名称
	 * @param param Object[] 存储过程所用的传入和传出参数
	 * @return list
	 * @throws SQLException
	 */
	public List getPageBySqlquery(String produce, Object[] param)  {
		Session session = HibernateSessionFactory.getSession();
		
		String str="";
		for(int i=0;i<param.length;i++){
			str+="?,";
		}
		str="("+str.substring(0,str.length() - 1)+")}";
		
		produce = "{Call " + produce + str;
		SQLQuery query = session.createSQLQuery(produce);

		for (int i = 0; i < param.length; i++) {
			query.setParameter(i, param[i]);
		}
		query.setResultTransformer(Transformers.ALIAS_TO_ENTITY_MAP); // 以map的形式返回

		List list = query.list();
		session.close();
		return list;

	}

Junit调用:

	@Test
	public void testGetPage() {
		long begin = System.currentTimeMillis(); 
		 Object[] ob={"T_Book","id",0,0,"*",10,1,"",0};
		 System.out.println(GsonUtil.serialize(hib.getPage("sp_page", ob)));
		 long end = System.currentTimeMillis(); 
		 System.out.println((end-begin)/1000.0);
	}

	@Test
	public void testGetPageBySqlquery() {
		long begin = System.currentTimeMillis(); 
		Object[] ob={"T_Book","id",0,0,"*",10,1,"",0};
		 System.out.println(GsonUtil.ListToGson(hib.getPageBySqlquery("sp_page",ob)));
		 long end = System.currentTimeMillis(); 
		 System.out.println((end-begin)/1000.0);
	}

注意:以上的方法1可以返回视图和输出参数(总页数),方法2则只能返回视图

建议:页面第一次加载可以使用方法1,之后的页面跳转可以使用方法2;页可以全部使用方法1

原文链接:https://www.idaobin.com/archives/2127.html

让我恰个饭吧.ヘ( ̄ω ̄ヘ)

支付宝 ——————- 微信
图片加载中图片加载中



恰饭广告

发表评论

您的电子邮箱地址不会被公开。 必填项已用*标注

2 + 5 =