ITPub博客

首页 > Linux操作系统 > Linux操作系统 > SQL 2000 2005通用存储过程

SQL 2000 2005通用存储过程

原创 Linux操作系统 作者:iSQlServer 时间:2009-02-25 17:01:40 0 删除 编辑

SQL2000通用存储过程(适用高版本):

 

Code
  CREATE PROC P_viewPage

    /**//**//**//*
        nzperfect [no_mIss] 高效通用分页存储过程(双向检索) 2007.5.7  QQ:34813284
        敬告:适用于单一主键或存在唯一值列的表或视图
        ps:Sql语句为8000字节,调用时请注意传入参数及sql总长度不要超过指定范围
          
    */

    @TableName VARCHAR(200),     --表名
    @FieldList VARCHAR(2000),    --显示列名,如果是全部字段则为*
    @PrimaryKey VARCHAR(100),    --单一主键或唯一值键
    @Where VARCHAR(2000),        --查询条件 不含'where'字符,如id>10 and len(userid)>9
    @Order VARCHAR(1000),        --排序 不含'order by'字符,如id asc,userid desc,必须指定asc或desc                                
                                 --注意当@SortType=3时生效,记住一定要在最后加上主键,否则会让你比较郁闷
    @SortType INT,               --排序规则 1:正序asc 2:倒序desc 3:多列排序方法
    @RecorderCount INT,          --记录总数 0:会返回总记录
    @PageSize INT,               --每页输出的记录数
    @PageIndex INT,              --当前页数
    @TotalCount INT OUTPUT,      --记返回总记录
    @TotalPageCount INT OUTPUT   --返回总页数
AS
    SET NOCOUNT ON

    IF ISNULL(@TotalCount,'') = '' SET @TotalCount = 0
    SET @Order = RTRIM(LTRIM(@Order))
    SET @PrimaryKey = RTRIM(LTRIM(@PrimaryKey))
    SET @FieldList = REPLACE(RTRIM(LTRIM(@FieldList)),' ','')

    WHILE CHARINDEX(', ',@Order) > 0 OR CHARINDEX(' ,',@Order) > 0
    BEGIN
        SET @Order = REPLACE(@Order,', ',',')
        SET @Order = REPLACE(@Order,' ,',',')   
    END

    IF ISNULL(@TableName,'') = '' OR ISNULL(@FieldList,'') = ''
        OR ISNULL(@PrimaryKey,'') = ''
        OR @SortType < 1 OR @SortType >3
        OR @RecorderCount  < 0 OR @PageSize < 0 OR @PageIndex < 0       
    BEGIN
        PRINT('ERR_00')      
        RETURN
    END   

    IF @SortType = 3
    BEGIN
        IF (UPPER(RIGHT(@Order,4))!=' ASC' AND UPPER(RIGHT(@Order,5))!=' DESC')
        BEGIN PRINT('ERR_02') RETURN END
    END

    DECLARE @new_where1 VARCHAR(1000)
    DECLARE @new_where2 VARCHAR(1000)
    DECLARE @new_order1 VARCHAR(1000)  
    DECLARE @new_order2 VARCHAR(1000)
    DECLARE @new_order3 VARCHAR(1000)
    DECLARE @Sql VARCHAR(8000)
    DECLARE @SqlCount NVARCHAR(4000)

    IF ISNULL(@where,'') = ''
        BEGIN
            SET @new_where1 = ' '
            SET @new_where2 = ' WHERE  '
        END
    ELSE
        BEGIN
            SET @new_where1 = ' WHERE ' + @where
            SET @new_where2 = ' WHERE ' + @where + ' AND '
        END

    IF ISNULL(@order,'') = '' OR @SortType = 1  OR @SortType = 2
        BEGIN
            IF @SortType = 1
            BEGIN
                SET @new_order1 = ' ORDER BY ' + @PrimaryKey + ' ASC'
                SET @new_order2 = ' ORDER BY ' + @PrimaryKey + ' DESC'
            END
            IF @SortType = 2
            BEGIN
                SET @new_order1 = ' ORDER BY ' + @PrimaryKey + ' DESC'
                SET @new_order2 = ' ORDER BY ' + @PrimaryKey + ' ASC'
            END
        END
    ELSE
        BEGIN
            SET @new_order1 = ' ORDER BY ' + @Order
        END

    IF @SortType = 3 AND  CHARINDEX(','+@PrimaryKey+' ',','+@Order)>0
        BEGIN
            SET @new_order1 = ' ORDER BY ' + @Order
            SET @new_order2 = @Order + ','           
            SET @new_order2 = REPLACE(REPLACE(@new_order2,'ASC,','{ASC},'),'DESC,','{DESC},')           
            SET @new_order2 = REPLACE(REPLACE(@new_order2,'{ASC},','DESC,'),'{DESC},','ASC,')
            SET @new_order2 = ' ORDER BY ' + SUBSTRING(@new_order2,1,LEN(@new_order2)-1)           
            IF @FieldList <> '*'
                BEGIN           
                    SET @new_order3 = REPLACE(REPLACE(@Order + ',','ASC,',','),'DESC,',',')                             
                    SET @FieldList = ',' + @FieldList                   
                    WHILE CHARINDEX(',',@new_order3)>0
                    BEGIN
                        IF CHARINDEX(SUBSTRING(','+@new_order3,1,CHARINDEX(',',@new_order3)),','+@FieldList+',')>0
                        BEGIN
                        SET @FieldList =
                            @FieldList + ',' + SUBSTRING(@new_order3,1,CHARINDEX(',',@new_order3))                       
                        END
                        SET @new_order3 =
                        SUBSTRING(@new_order3,CHARINDEX(',',@new_order3)+1,LEN(@new_order3))
                    END
                    SET @FieldList = SUBSTRING(@FieldList,2,LEN(@FieldList))                    
                END           
        END

    SET @SqlCount = 'SELECT @TotalCount=COUNT(*),@TotalPageCount=CEILING((COUNT(*)+0.0)/'
                    + CAST(@PageSize AS VARCHAR)+') FROM ' + @TableName + @new_where1
   
    IF @RecorderCount  = 0
        BEGIN
             EXEC SP_EXECUTESQL @SqlCount,N'@TotalCount INT OUTPUT,@TotalPageCount INT OUTPUT',
                               @TotalCount OUTPUT,@TotalPageCount OUTPUT
        END
    ELSE
        BEGIN
             SELECT @TotalCount = @RecorderCount           
        END

    IF @PageIndex > CEILING((@TotalCount+0.0)/@PageSize)
        BEGIN
            SET @PageIndex =  CEILING((@TotalCount+0.0)/@PageSize)
        END

    IF @PageIndex = 1 OR @PageIndex >= CEILING((@TotalCount+0.0)/@PageSize)
        BEGIN
            IF @PageIndex = 1 --返回第一页数据
                BEGIN
                    SET @Sql = 'SELECT TOP ' + STR(@PageSize) + ' ' + @FieldList + ' FROM '
                               + @TableName + @new_where1 + @new_order1
                END
            IF @PageIndex >= CEILING((@TotalCount+0.0)/@PageSize)  --返回最后一页数据
                BEGIN
                    SET @Sql = 'SELECT TOP ' + STR(@PageSize) + ' ' + @FieldList + ' FROM ('
                               + 'SELECT TOP ' + STR(ABS(@PageSize*@PageIndex-@TotalCount-@PageSize))
                               + ' ' + @FieldList + ' FROM '
                               + @TableName + @new_where1 + @new_order2 + ' ) AS TMP '
                               + @new_order1                   
                END       
        END   
    ELSE
        BEGIN
            IF @SortType = 1  --仅主键正序排序
                BEGIN
                    IF @PageIndex <= CEILING((@TotalCount+0.0)/@PageSize)/2  --正向检索
                        BEGIN
                            SET @Sql = 'SELECT TOP ' + STR(@PageSize) + ' ' + @FieldList + ' FROM '
                                       + @TableName + @new_where2 + @PrimaryKey + ' > '
                                       + '(SELECT MAX(' + @PrimaryKey + ') FROM (SELECT TOP '
                                       + STR(@PageSize*(@PageIndex-1)) + ' ' + @PrimaryKey
                                       + ' FROM ' + @TableName
                                       + @new_where1 + @new_order1 +' ) AS TMP) '+ @new_order1
                        END
                    ELSE  --反向检索
                        BEGIN
                            SET @Sql = 'SELECT TOP ' + STR(@PageSize) + ' ' + @FieldList + ' FROM ('
                                       + 'SELECT TOP ' + STR(@PageSize) + ' '
                                       + @FieldList + ' FROM '
                                       + @TableName + @new_where2 + @PrimaryKey + ' < '
                                       + '(SELECT MIN(' + @PrimaryKey + ') FROM (SELECT TOP '
                                       + STR(@TotalCount-@PageSize*@PageIndex) + ' ' + @PrimaryKey
 

SQL2005通用存储过程:

 

Code
set ANSI_NULLS ON
set QUOTED_IDENTIFIER ON
GO
-- =============================================
-- Description:    <高效分页存储过程,仅适用于Sql2005>
-- Notes:        <排序字段强烈建议建索引>
-- =============================================
ALTER Procedure [dbo].[up_Page2005] 
 @TableName varchar(500),        --表名
 @Fields varchar(8000) = '*',    --字段名(全部字段为*)
 @OrderField varchar(8000),        --排序字段(必须!支持多字段)
 @sqlWhere varchar(8000) = Null,--条件语句(不用加where)
 @pageSize int,                    --每页多少条记录
 @pageIndex int = 1 ,            --指定当前为第几页
 @TotalPage int output            --返回总页数 
as
begin

    Begin Tran --开始事务

    Declare @sql nvarchar(4000);
    Declare @totalRecord int;    

    --计算总记录数
         
    if (@SqlWhere='' or @sqlWhere=NULL)
        set @sql = 'select @totalRecord = count(*) from ' + @TableName
    else
        set @sql = 'select @totalRecord = count(*) from ' + @TableName + ' where ' + @sqlWhere

 

    EXEC sp_executesql @sql,N'@totalRecord int OUTPUT',@totalRecord OUTPUT--计算总记录数        
    
    --计算总页数
    select @TotalPage=CEILING((@totalRecord+0.0)/@PageSize)

    if (@SqlWhere='' or @sqlWhere=NULL)
        set @sql = 'Select * FROM (select ROW_NUMBER() Over(order by ' + @OrderField + ') as rowId,' + @Fields + ' from ' + @TableName 
    else
        set @sql = 'Select * FROM (select ROW_NUMBER() Over(order by ' + @OrderField + ') as rowId,' + @Fields + ' from ' + @TableName + ' where ' + @SqlWhere    
        
    
    --处理页数超出范围情况
    if @PageIndex<=0 
        Set @pageIndex = 1
    
    if @pageIndex>@TotalPage
        Set @pageIndex = @TotalPage

     --处理开始点和结束点
    Declare @StartRecord int
    Declare @EndRecord int
    
    set @StartRecord = (@pageIndex-1)*@PageSize + 1
    set @EndRecord = @StartRecord + @pageSize - 1

    --继续合成sql语句
    set @Sql = @Sql + ') as ' + @TableName + ' where rowId between ' + Convert(varchar(50),@StartRecord) + ' and ' +  Convert(varchar(50),@EndRecord)
    --print @sql ;
    Exec(@Sql)
    ---------------------------------------------------
    If @@Error <> 0
      Begin
        RollBack Tran
        Return -1
      End
    Else
      Begin
        Commit Tran
        Return @totalRecord ---返回记录总数
   End
end

 

来自 “ ITPUB博客 ” ,链接:http://blog.itpub.net/16436858/viewspace-557807/,如需转载,请注明出处,否则将追究法律责任。

请登录后发表评论 登录
全部评论

注册时间:2008-10-17

  • 博文量
    1319
  • 访问量
    2101561