说是struts分页,实际上这个分页类不局限在某个框架下用的
实现方法是通过list和 map 来封装数据结果集省了建立formbean和手动对formbean赋值的麻烦,
用list和 map 来封装后使用起来和rs基本上一样,有些地方比RS方便些。
本分页类中对查询参数已经作了处理,所以不需要在自己在去拼URL参数了。
sql server分页使用存储过程要更高效些
下面这个存储过程是从SQL区找到的
-----------------------------------------------------------------------------------------------------------------------------------
CREATE Proc p_show
@QueryStr varchar(8000), --表名、视图名、查询语句
@PageSize int=10, --每页的大小(行数)
@PageCurrent int=1, --要显示的页
@FdShow varchar (8000)='', --要显示的字段列表,如果查询结果有标识字段,需要指定此值,且不包含标识字段
@FdOrder nvarchar (3000)='' --排序字段列表
as
declare @FdName nvarchar(550) --表中的主键或表、临时表中的标识列名
,@Id1 varchar(80),@Id2 varchar(80) --开始和结束的记录号
,@Obj_ID int --对象ID
--表中有复合主键的处理
declare @strfd nvarchar(4000) --复合主键列表
,@strjoin varchar(8000) --连接字段
,@strwhere nvarchar(4000) --查询条件
select @Obj_ID=object_id(@QueryStr)
,@FdShow=case isnull(@FdShow,'') when '' then ' *' else ' '+@FdShow end
,@FdOrder=case isnull(@FdOrder,'') when '' then '' else ' order by '+@FdOrder end
,@QueryStr=case when @Obj_ID is not null then ' '+@QueryStr else ' ('+@QueryStr+') a' end
--如果显示第一页,可以直接用top来完成
if @PageCurrent=1
begin
select @Id1=cast(@PageSize as varchar(50))
exec('select top '+@Id1+@FdShow+' from '+@QueryStr+@FdOrder)
return
end
--如果是表,则检查表中是否有标识更或主键
if @Obj_ID is not null and objectproperty(@Obj_ID,'IsTable')=1
begin
select @Id1=cast(@PageSize as varchar(50))
,@Id2=cast((@PageCurrent-1)*@PageSize as varchar(50))
select @FdName=name from syscolumns where id=@Obj_ID and status=0x80
if @@rowcount=0 --如果表中无标识列,则检查表中是否有主键
begin
if not exists(select 1 from sysobjects where parent_obj=@Obj_ID and xtype='PK')
goto lbusetemp --如果表中无主键,则用临时表处理
select @FdName=name from syscolumns where id=@Obj_ID and colid in(
select colid from sysindexkeys where @Obj_ID=id and indid in(
select indid from sysindexes where @Obj_ID=id and name in(
select name from sysobjects where xtype='PK' and parent_obj=@Obj_ID
)))
if @@rowcount>1 --检查表中的主键是否为复合主键
begin
select @strfd='',@strjoin='',@strwhere=''
select @strfd=@strfd+',['+name+']'
,@strjoin=@strjoin+' and a.['+name+']=b.['+name+']'
,@strwhere=@strwhere+' and b.['+name+'] is null'
from syscolumns where id=@Obj_ID and colid in(
select colid from sysindexkeys where @Obj_ID=id and indid in(
select indid from sysindexes where @Obj_ID=id and name in(
select name from sysobjects where xtype='PK' and parent_obj=@Obj_ID
)))
select @strfd=substring(@strfd,2,2000)
,@strjoin=substring(@strjoin,5,4000)
,@strwhere=substring(@strwhere,5,4000)
goto lbusepk
end
end
end
else
goto lbusetemp
/*--使用标识列或主键为单一字段的处理方法--*/
lbuseidentity:
exec('select top '+@Id1+@FdShow+' from '+@QueryStr
+' where '+@FdName+' not in(select top '
+@Id2+''+@FdName+' from '+@QueryStr+@FdOrder
+')'+@FdOrder
)
return
/*--表中有复合主键的处理方法--*/
lbusepk:
exec('select '+@FdShow+' from(select top '+@Id1+' a.* from
(select top 100 percent * from '+@QueryStr+@FdOrder+') a
left join (select top '+@Id2+''+@strfd+'
from '+@QueryStr+@FdOrder+') b on '+@strjoin+'
where '+@strwhere+') a'
)
return
/*--用临时表处理的方法--*/
lbusetemp:
select @FdName='[ID_'+cast(newid() as varchar(80))+']'
,@Id1=cast(@PageSize*(@PageCurrent-1) as varchar(50))
,@Id2=cast(@PageSize*@PageCurrent-1 as varchar(50))
exec('select '+@FdName+'=identity(int,0,1),'+@FdShow+'
into #tb from'+@QueryStr+@FdOrder+'
select '+@FdShow+' from #tb where '+@FdName+' between '
+@Id1+' and '+@Id2
)
GO
--------------------------------------------------------------------------------------------------------------------------------
这里需要建立一个分页类ResultGatherPro.java
相关说明在相应行的后面
--------------------------------------------------------------------------------------------------------------------------------
import conn.DBConnManager;//这个是连接池,可以更换其他的。
import javax.servlet.http.HttpServletRequest;
import java.sql.*;
import java.util.*;
public class ResultGatherPro {
private String sql;
private int intPageSize; //每页行数
private int intRowCount;
private int intPageCount;
private int intPage; //页号
private String Counter;
DBConnManager conn = null;
Connection con = null;
CallableStatement stmt = null;
ResultSet rs = null;
Statement st = null;
ResultSet rsc = null;
private String defaultname = "default";
public ResultGatherPro() {
}
public ResultGatherPro(String sqlcom, int rownum, int pagenum, String counter) {
System.out.println(counter);
sql = sqlcom;
intPageSize = rownum;
intPage = pagenum;
Counter = counter;
System.out.println(sqlcom);
}
public void setUseDB(String dbname)
{
this.defaultname = dbname;
}
public List selectRS(String sqlcom, int rownum, int pagenum, String counter) {
System.out.println(counter);
this.sql = sqlcom;
this.intPageSize = rownum;
this.intPage = pagenum;
this.Counter = counter;
System.out.println(sqlcom);
return selectRS();
}
public List selectRS() {
List rsall = new ArrayList();
Map rsTree;
try {
conn = DBConnManager.getInstance();
con = conn.getConnection(defaultname);
st = con.createStatement();
rsc = st.executeQuery(Counter);
while (rsc.next()) {
intRowCount = rsc.getInt("allrow");
}
stmt = con.prepareCall("{call p_show('" + sql + "'," + intPageSize + "," + intPage + ")}");//如果用别的数据库就把这个地方修改一下
rs = stmt.executeQuery();
ResultSetMetaData rsmd = rs.getMetaData();
int numberOfColumns = rsmd.getColumnCount();
//Object[] aa = new Object[numberOfColumns-1];
intPageCount = (intRowCount + intPageSize - 1) / intPageSize;
while (rs.next()) {
rsTree = new HashMap(numberOfColumns);
for (int r = 1; r < numberOfColumns + 1; r++) {
rsTree.put(rsmd.getColumnName(r).toLowerCase(), rs.getObject(r));//toLowerCase()这个地方把列名转化为小写是为了和oracle兼容
}
rsall.add(rsTree);
}
} catch (java.lang.Exception ex) {
System.out.println("db conn has a Exception !!!!");
if(ex.toString().indexOf("peer")>0||ex.toString().indexOf("reset")>0) //一般连接池都没有自动重连功能,这里是当数据库连接异常后,进行重新初始化连接。不然即使网络正常了,数据库连接也不会恢复
DBConnManager.reConnect();
ex.printStackTrace();
} finally {
try {
if (rsc != null)
rsc.close();
if (st != null)
st.close();
if (rs != null)
rs.close();
if (stmt != null)
stmt.close();
if (conn != null)
conn.releaseConnection(defaultname, con);
} catch (Exception e) {
System.out.println(e);
}
}
return rsall;
}
public String ChangePage(HttpServletRequest request) {
String urlchange = null;
String pagename = request.getRequestURI().substring(request.getRequestURI().lastIndexOf("/") + 1);
String url = getUrl(request);
String dol = "";
if (url != null && !url.equals(""))
dol = "&";
if (intPage > 1 && intPage < intPageCount) {
urlchange = "<a href=" + pagename + "?pagenum=" + (intPage - 1) + dol + url + ">上一页</a> | <a href=" + pagename + "?pagenum=" + (intPage + 1) + dol + url + ">下一页</a> | 第" + intPage + "页 | 共" + intPageCount + "页 | 共" + intRowCount + "条";
} else if (intPage == 1 && intRowCount <= intPageSize) {
urlchange = "上一页 | 下一页 | 第" + intPage + "页 | 共" + intPageCount + "页 | 共" + intRowCount + "条";
} else if (intPage == intPageCount && intPage != 1) {
urlchange = "<a href=" + pagename + "?pagenum=" + (intPage - 1) + dol + url + ">上一页</a> 下一页 | 第" + intPage + "页 | 共" + intPageCount + "页 | 共" + intRowCount + "条";
} else if (intPage == 1 && intRowCount >= intPageSize) {
urlchange = "上一页 | <a href=" + pagename + "?pagenum=" + (intPage + 1) + dol + url + ">下一页</a> | 第" + intPage + "页 | 共" + intPageCount + "页 | 共" + intRowCount + "条";
} else {
urlchange = "<a href=" + pagename + ">第一页</a>";
}
return urlchange;
}
public String ChangeBar(HttpServletRequest request) {
String urlchange = null;
String pagename = request.getRequestURI().substring(request.getRequestURI().lastIndexOf("/") + 1);
String url = getUrl(request);
String dol = "";
if (url != null && !url.equals(""))
dol = "&";
if (intPage > 1 && intPage < intPageCount) {
urlchange = "<a href=" + pagename + "?pagenum=" + (intPage - 1) + dol + url + ">上一页</a> | <a href=" + pagename + "?pagenum=" + (intPage + 1) + dol + url + ">下一页</a> | 第" + intPage + "页 | 共" + intPageCount + "页";
} else if (intPage == 1 && intRowCount <= intPageSize) {
urlchange = "上一页 | 下一页 | 第" + intPage + "页 | 共" + intPageCount + "页";
} else if (intPage == intPageCount && intPage != 1) {
urlchange = "<a href=" + pagename + "?pagenum=" + (intPage - 1) + dol + url + ">上一页</a> 下一页 | 第" + intPage + "页 | 共" + intPageCount + "页";
} else if (intPage == 1 && intRowCount >= intPageSize) {
urlchange = "上一页 | <a href=" + pagename + "?pagenum=" + (intPage + 1) + dol + url + ">下一页</a> | 第" + intPage + "页 | 共" + intPageCount + "页";
} else {
urlchange = "<a href=" + pagename + ">第一页</a>";
}
return urlchange;
}
public int getTotal() {
return intRowCount;
}
public int getPageCount() {
return intPageCount;
}
public String gotoPage(HttpServletRequest request) {
String url = getUrl(request);
String javascript = "<script>function checksearch(sform)\n{if(sform.pagenum.value==\"\" || sform.pagenum.value==\"0\"){alert('请输正确入页数!');sform.pagenum.focus();return false;}\nif(isNaN(sform.pagenum.value)){alert('请输入数字!');sform.pagenum.focus();return false;}}</script>";
String form = "<table border='0' cellpadding='0' cellspacing='0'>\n" + javascript;
form += "<form action='' onSubmit='return checksearch(this)'>\n<tr><td width='40' align='center'>\n<input name='pagenum' type='text' size='3' class='gotext'>\n ";
if (url != null) {
if (url.indexOf("&") > 0) {
String[] param = new String[(url.split("&")).length];
param = url.split("&");
for (int i = 0; i < param.length; i++) {
form += "<input type='hidden' name='" + param[i].substring(0, param[i].indexOf("=")) + "' value='" + param[i].substring(param[i].indexOf("=") + 1) + "'>\n";
}
} else {
if (url.indexOf("=") > 0) {
form += "<input type='hidden' name='" + url.substring(0, url.indexOf("=")) + "' value='" + url.substring(url.indexOf("=") + 1) + "'>\n";
}
}
}
form += "</td><td width='25' align='center'><input type='submit' name='Submit' value='GO' class='gobtn'>\n</td>\n</tr>\n</form>\n</table>";
return form;
}
private String getUrl(HttpServletRequest request) {
String url = "";
Enumeration param = request.getParameterNames();
while (param.hasMoreElements()) {
String pname = param.nextElement().toString();
if (!pname.equalsIgnoreCase("pagenum") && !pname.equalsIgnoreCase("submit"))
url += pname + "=" + request.getParameter(pname) + "&";
}
if (url.endsWith("&")) {
url = url.substring(0, url.lastIndexOf("&"));
}
return url;
}
public String intercept(String str, int num, String last) {
if (str.length() <= num)
return str;
else
return str.substring(0, num) + last;
}
}
--------------------------------------------------------------------------------------------------------
在action里可以这样调用
可以看到action里没有做对传递参数的处理,只需要把request整个传到分页类里就可以了
--------------------------------------------------------------------------------------------------------------
String sql = "select top 100 percent * from usertable";
String sqlcount = "select count(*) from usertable";//为了得到总行数
int pagesize= 18;
int pagenum = 1;
if(request.getParameter("pagenum")!=null)
{
pagenum = java.lang.Integer.parseInt(request.getParameter("pagenum"));
}
ResultGatherPro rs = new ResultGatherPro(sql,pagesize,pagenum,sqlcount);
request.setAttribute("liststill",rs.selectRS());
request.setAttribute("changepage",rs.ChangePage(request));
request.setAttribute("gotopage",rs.gotoPage(request));
-----------------------------------------------------------------------------------------------------------------------------------
最后 jsp里可以这样写
-------------------------------------------------------------------------------------------------------------------------
<logic:iterate id="listuser" name="liststill" type="Map">
<bean:write name='listuser' property='username'/>
<bean:write name='listuser' property='useremail'/>
</logic:iterate>
<bean:write name='changepage' filter="false"/>
<bean:write name='gotopage' filter="false"/>
上面两个一定要设置filter="false" 不然会过滤html部分
如果用mysql数据库
将分页类中
con.prepareCall("{call p_show('" + sql + "'," + intPageSize + "," + intPage + ")}");
改成
con.prepareCall(sql+" limit "+(intPage-1)*intPageSize+","+intPageSize);
如果用oracle数据库
改成
con.prepareCall("SELECT * FROM(SELECT A.*, rownum r FROM("+sql+") A WHERE rownum <= "+intPage*intPageSize+") B WHERE r > "+(intPage-1)
*intPageSize);
最好不要用把所有记录都读出来然后在其中进行分页的方法