http://blog.itpub.net/29254281/viewspace-2149120/
http://blog.itpub.net/29254281/viewspace-2149309/
处理这种每隔N行生成一个汇总行的需求,一共有三种方式
-
drop table t;
-
create table t (c int);
-
insert into t values
-
(15),(7),(9),(10),(7),(8),(20),(16),(9),(19),
-
(14),(10),(11),(10),(10),(12),(7),(10),(7),(9);
-
commit;
-
-
- select * from t;

为了简单,就按照这个自然顺序 ,每三行生成一个汇总行,sum前三行的值。
第一招,效率低下容易理解
- select case when c is null then '汇总' else '' end s,ifnull(c,sumc) c from (
- select ceil(id/3) l,c,null sumc
- from
- (
- select @id:=@id+1 id, t1.* from t t1,(select @id:=0) vars
- ) t2
- union all
- select ceil(id/3) l,null,sum(c)
- from
- (
- select @id1:=@id1+1 id, t1.* from t t1,(select @id1:=0) vars
- ) t3
- group by l
- ) t order by l,ifnull(c,'9999');
结果:

第二招,数字辅助表补全. 性能较好. 计算汇总行,理解稍微复杂.
先增加一个数字辅助表 nums
-
create table nums(id int not null primary key);
-
-
delimiter $$
-
create procedure pCreateNums(cnt int)
-
begin
-
declare s int default 1;
-
truncate table nums;
-
while s<=cnt do
-
insert into nums select s;
-
set s=s+1;
-
end while;
-
end $$
-
delimiter ;
-
-
delimiter $$
-
create procedure pFastCreateNums(cnt int)
-
begin
-
declare s int default 1;
-
truncate table nums;
-
insert into nums select s;
-
while s*2<=cnt do
-
insert into nums select id+s from nums;
-
set s=s*2;
-
end while;
-
end $$
- delimiter ;
初始化数字辅助表
call pFastCreateNums(100000);
然后
- select s,ifnull(c,cc) c
- from (
- select
- case when rn is null then '汇总' else '' end s,
- t4.c,
- if(mod(t3.id,4)!=0 ,case when @total=-1 then @total:=t4.c else @total:=@total+t4.c end,@total) cc,
- case when mod(t3.id,4)=0 then @total:=-1 else null end
- from (
- select * from nums where id<=
- (select (ceil(count(*)/4)+1)*5 from t )
- ) t3
- left join (
- select
- case when mod(@rn+1,4)=0 then @rn:=@rn+2 else @rn:=@rn+1 end rn ,
- t1.* from t t1,(select @rn:=0,@total:=0) vars
- ) t4 on(t3.id=t4.rn)
- ) result;
这个理解稍微有点复杂,
第二招改进版本
- select s,ifnull(c,cc) c
- from (
- select
- case when rn is null then '汇总' else '' end s,
- t4.c,
- case when t4.c is not null then @total:=@total+t4.c when t4.c is null then @total+(@total:=0) end cc
- from (
- select * from nums where id<=
- (select (ceil(count(*)/4)+1)*5 from t )
- ) t3
- left join (
- select
- case when mod(@rn+1,4)=0 then @rn:=@rn+2 else @rn:=@rn+1 end rn ,
- t1.* from t t1,(select @rn:=0,@total:=0) vars
- ) t4 on(t3.id=t4.rn)
- ) result where ifnull(c,cc) is not null;
好理解多了,只是有冗余行数。

第三招,又是王工的大招. 性能比第二招快15%-20%。可读性强 好理解。整体还简短。
- select case when id is null then '汇总' else '' end s,sum(c) c from (
- select @id:=@id+1 id, t1.* from t t1,(select @id:=0) vars
- ) t2
- group by ceil(t2.id/3),t2.id with rollup;