随笔-61  评论-13  文章-19  trackbacks-0

日志报表查询

最近在做一个流水表的报表查询,做下小结。

一般情况下对于数据量比较大的流水日志,都是按月隔接存储的,所以在生成跨月甚至是跨年报表的时候,需要做特殊的处理。以下记录我的处理方式,供参考。

思路:

1、  生成临时表:查询出的数据都放在该临时表。

2、  按月查询:将查询条件中的开始时间到结束时间之间的数据按月依次查询。

3、  查询:(Oracle数据库)

参数定义:Start_Date 开始时间

          End_Date 结束时间

          Tmp_Date 当前时间

          Tmp_Data 临时数据表

          Month_TBName 月表名


Tmp_Date = Start_Date


While Tmp_Date < End_Date Loop


    
Month_TBName =  tuunc(Tmp_Date,’month’)


    Tmp_Date = Add_Months(Tmp_Data,1)    注:
下次查询为下月表数据


     If  Tmp_Date > End_Date


   
        
查询Month_TBName月表中日期Between Start_Date And End_Date的数据,放入Tmp_Data 
         

Else


    
        
查询Month_TBName全月表数据,放入Tmp_Data


 End Loop

  3、 存储过程
    --SP统计
    procedure xp_SPStat(areacode    varchar2,
                        songId      varchar2,
                        dateStart   varchar2,
                        dateEnd     varchar2,
                        spID        varchar2,
                        page        number, --之前显示的页码
                        pageSize    number, --页大小
                        pageAction  varchar2, --翻页命令:first、last、next、pre
                        total       out number, --记录总数
                        currentPage out number, --当前页码
                        totalPage   out number, --总页数
                        ret         out number, --操作结果
                        rec_rc      out ret_record --结果集
                        ) is
        tablename varchar2(100);
        sqlstr    varchar2(256) := '';
        num_start number; --个数下限
        num_end   number; --个数上限
        sqlstry  varchar2(256) := '';
    begin
        if isStatOverSpaned(dateStart, dateEnd) then
            --时间范围过大
            ret := ret_err_overspan;
            return;
        end if;
        if statTempTable(areacode,songId,spID,dateStart, dateEnd, tablename) = false then
            ret := ret_err_tmptable;
            return;
        end if;
        --获取总数
        select count(*)
          into total
          from (select t.song_id, count(*) as statCount
                  from tsongdeallogtemp t
                
                 group by t.song_id);
        --翻页处理
        pageTurn(page, pageSize, total, pageAction, currentPage, totalPage);
        num_start := (currentPage - 1) * pagesize + 1;
        num_end   := currentPage * pagesize;

        --获取数据集
        open rec_rc for
            select *
              from (select c. *, rownum rn
                      from (select a.statcount,
                           (select count(a.statcount) from (select  count(*) as statcount
                                      from tsongdeallogtemp t)
                           ) FSTATCOUNT, b. *
                              from (select t.song_id, count(*) as statcount
                                      from tsongdeallogtemp t
                                    
                                     group by t.song_id) a,
                                   tSong b
                             where a.song_id = b.song_id
                             order by a.statcount desc) c)
             where rn between num_start and num_end;
        ret := ret_ok;

    exception
        when others then
            sqlstry :=sqlerrm;
            ret := ret_Failed;
    end;

   --sp统计临时表操作
   function statTempTable(vareacode  varchar2,
                           vsongId    varchar2,
                           vspID      varchar2,
                           vdateStart varchar2,
                           vdateEnd   varchar2,
                           pTabName  out varchar2) return boolean is
        ret       boolean := false;
        tmp_date  date := to_date(vdateStart, 'YYYY-MM-DD');
        v_dateS   date := to_date(vdateStart, 'YYYY-MM-DD');
        v_dateE   date := to_date(vdateEnd, 'YYYY-MM-DD');
        tmpCount  number := 0;
        iCount    number := 0;
        tablename varchar2(100);
        sqlstr    varchar2(516);
        tempSql   varchar2(100);
    begin
        --获取临时表名
        tablename := getSongDealTabName(1);
        pTabName  := tablename;
        sqlstr    := 'delete from ' || tablename;
        execute immediate sqlstr;
    
        --往临时表中写入数据
        while tmp_date <= to_date(vdateEnd ||'23:59:59', 'YYYY-MM-DD HH24:MI:SS') loop
            tablename := 'TSONGDEALLOG' ||
                         to_char(trunc(tmp_date, 'month'), 'YYYYMM');
            select count(*)
              into iCount
              from tab t
             where t.tname = tablename;
            if iCount <= 0 then
                return ret;
            end if;
            tmp_date := add_months(tmp_date, 1);
            tmpCount := tmpCount + 1;
           
            if vsongId is not null then
              tempSql:=' t.song_id='''||vsongId||''' ';
            else
              tempSql:=' t.song_id like '''||vspID||'%'' ';
            end if; 
           
           
            if tmp_date >= to_date(vdateEnd||'23:59:59', 'YYYY-MM-DD HH24:MI:SS') then

                sqlstr := 'insert into tsongdeallogtemp ( select * from ' ||
                          tablename || ' t where '|| tempSql ||
                          ' and t.PHONE_CODE like '''||vareacode||'%'''||
                          ' and t.add_time   between '||
                          'to_date('''||vdateStart|| ' 00:00:00'',''yyyy-mm-dd HH24:MI:SS'')  and ' ||
                          'to_date('''||vdateEnd|| ' 23:59:59'',''yyyy-mm-dd HH24:MI:SS''))';
                execute immediate sqlstr  ;
            else
                sqlstr := 'insert into tsongdeallogtemp select * from ' ||
                          tablename || ' t where '|| tempSql ||
                          ' and t.PHONE_CODE like '''||vareacode||'%''';
                execute immediate sqlstr  ;
            end if;

        end loop;
        commit;
        return true;
    exception
        when others then
        sqlstr:=sqlerrm;
            return false;
            rollback;
    end;

posted on 2006-03-14 16:10 xnabx 阅读(465) 评论(0)  编辑  收藏 所属分类: 3、DataBase

只有注册用户登录后才能发表评论。


网站导航: