1、存储过程实现版
SP 代码:
DELIMITER $$
DROP PROCEDURE IF EXISTS `test`.`sp_row_column_wrap`$$
CREATE DEFINER=`root`@`localhost` PROCEDURE `sp_row_column_wrap`(IN $schema_name varchar(64),
IN $table_name varchar(64))
BEGIN
declare cnt int(11);
declare $table_rows int(11);
declare i int(11);
declare j int(11);
declare s int(11);
declare str varchar(255);
-- Get the column number of the table
select count(1) from information_schema.columns where table_schema=$schema_name andtable_name=$table_name into cnt;
-- Get the row number of the table
select table_rows from information_schema.tables where table_schema = $schema_name andtable_name=$table_name into $table_rows;
-- Check whether the table exists or not
drop table if exists test.temp;
create table if not exists test.temp (`1` varchar(255) not null);
-- loop1 start
set i = 0;
loop1:loop
if i = $table_rows-1 then
leave loop1;
end if;
set @stmt1 = concat('alter table test.temp add `',i+2,'` varchar(255) not null');
prepare s1 from @stmt1;
execute s1;
deallocate prepare s1;
set @stmt1 = '';
set i = i + 1;
end loop loop1;
-- loop1 end;
set s = 0;
-- loop2 start
loop2:loop
-- leave loop2
if s=cnt then
leave loop2;
end if;
set @stmt2 = concat('select column_name from information_schema.columns where table_schema="',$schema_name,
'" and table_name="',$table_name,'" limit ',s,',1 into @temp;');
prepare s2 from @stmt2;
execute s2;
deallocate prepare s2;
set @stmt2 = '';
set j=0;
set str = ' select ';
-- Loop3 start
loop3:loop
if j = $table_rows then
leave loop3;
end if;
set @stmt3 = concat('select ',@temp,' from ',$schema_name,'.',$table_name,' limit ',j,',1 into @temp2;');
prepare s3 from @stmt3;
execute s3;
set str = concat(str,'"',@temp2,'"',',');
deallocate prepare s3;
set @stmt3 = '';
set j = j+1;
end loop loop3;
set str = left(str,length(str)-1);
-- insert new data into table
set @stmt4 = concat('insert into test.temp',str,';');
prepare s4 from @stmt4;
execute s4;
deallocate prepare s4;
set @stmt4 = '';
set s=s+1;
end loop loop2;
END$$
DELIMITER ;
以下是测试结果:
======
select * from a;
select * from b;
select * from salary;
call sp_row_column_wrap('test','a');
select * from test.temp;
call sp_row_column_wrap('test','b');
select * from test.temp;
call sp_row_column_wrap('test','salary');
select * from test.temp;
query result(2 records)
aid | title |
1 | 111 |
2 | 222 |
query result(3 records)
bid | aid | image | time |
1 | 2 | 1.gif | 2007-08-08 |
2 | 2 | 2.gif | 2007-08-09 |
3 | 2 | 3.gif | 2007-08-08 |
query result(7 records)
id | cost | des | Autoid |
1 | 10 | aaaa | 1 |
1 | 15 | bbbb | 2 |
1 | 20 | cccc | 3 |
2 | 80 | aaaa | 4 |
2 | 100 | bbbb | 5 |
2 | 60 | dddd | 6 |
3 | 500 | dddd | 7 |
query result(2 records)
1 | 2 |
1 | 2 |
111 | 222 |
query result(4 records)
1 | 2 | 3 |
1 | 2 | 3 |
2 | 2 | 2 |
1.gif | 2.gif | 3.gif |
2007-08-08 | 2007-08-09 | 2007-08-08 |
query result(4 records)
1 | 2 | 3 | 4 | 5 | 6 | 7 |
1 | 1 | 1 | 2 | 2 | 2 | 3 |
10 | 15 | 20 | 80 | 100 | 60 | 500 |
aaaa | bbbb | cccc | aaaa | bbbb | dddd | dddd |
1 | 2 | 3 | 4 | 5 | 6 | 7 |
二、普通SQL语句实现版
在某些数据库中有交叉表,但在MySQL中却没有这个功能,但网上看到有不少朋友想找出一个解决方法,特发贴集思广义。
http://topic.csdn.net/u/20090530/23/0b782674-4b0b-4cf5-bc1a-e8914aaee5ab.html?96198
现整理解法如下:
数据样本:
create table tx(
id int primary key,
c1 char(2),
c2 char(2),
c3 int
);
insert into tx values
(1 ,'A1','B1',9),
(2 ,'A2','B1',7),
(3 ,'A3','B1',4),
(4 ,'A4','B1',2),
(5 ,'A1','B2',2),
(6 ,'A2','B2',9),
(7 ,'A3','B2',8),
(8 ,'A4','B2',5),
(9 ,'A1','B3',1),
(10 ,'A2','B3',8),
(11 ,'A3','B3',8),
(12 ,'A4','B3',6),
(13 ,'A1','B4',8),
(14 ,'A2','B4',2),
(15 ,'A3','B4',6),
(16 ,'A4','B4',9),
(17 ,'A1','B4',3),
(18 ,'A2','B4',5),
(19 ,'A3','B4',2),
(20 ,'A4','B4',5);
mysql> select * from tx;
+----+------+------+------+
| id | c1 | c2 | c3 |
+----+------+------+------+
| 1 | A1 | B1 | 9 |
| 2 | A2 | B1 | 7 |
| 3 | A3 | B1 | 4 |
| 4 | A4 | B1 | 2 |
| 5 | A1 | B2 | 2 |
| 6 | A2 | B2 | 9 |
| 7 | A3 | B2 | 8 |
| 8 | A4 | B2 | 5 |
| 9 | A1 | B3 | 1 |
| 10 | A2 | B3 | 8 |
| 11 | A3 | B3 | 8 |
| 12 | A4 | B3 | 6 |
| 13 | A1 | B4 | 8 |
| 14 | A2 | B4 | 2 |
| 15 | A3 | B4 | 6 |
| 16 | A4 | B4 | 9 |
| 17 | A1 | B4 | 3 |
| 18 | A2 | B4 | 5 |
| 19 | A3 | B4 | 2 |
| 20 | A4 | B4 | 5 |
+----+------+------+------+
20 rows in set (0.00 sec)
mysql>
期望结果
+------+-----+-----+-----+-----+------+
|C1 |B1 |B2 |B3 |B4 |Total |
+------+-----+-----+-----+-----+------+
|A1 |9 |2 |1 |11 |23 |
|A2 |7 |9 |8 |7 |31 |
|A3 |4 |8 |8 |8 |28 |
|A4 |2 |5 |6 |14 |27 |
|Total |22 |24 |23 |40 |109 |
+------+-----+-----+-----+-----+------+
1. 利用SUM(IF()) 生成列 + WITH ROLLUP 生成汇总行,并利用 IFNULL将汇总行标题显示为 Total
mysql> SELECT
-> IFNULL(c1,'total') AS total,
-> SUM(IF(c2='B1',c3,0)) AS B1,
-> SUM(IF(c2='B2',c3,0)) AS B2,
-> SUM(IF(c2='B3',c3,0)) AS B3,
-> SUM(IF(c2='B4',c3,0)) AS B4,
-> SUM(IF(c2='total',c3,0)) AS total
-> FROM (
-> SELECT c1,IFNULL(c2,'total') AS c2,SUM(c3) AS c3
-> FROM tx
-> GROUP BY c1,c2
-> WITH ROLLUP
-> HAVING c1 IS NOT NULL
-> ) AS A
-> GROUP BY c1
-> WITH ROLLUP;
+-------+------+------+------+------+-------+
| total | B1 | B2 | B3 | B4 | total |
+-------+------+------+------+------+-------+
| A1 | 9 | 2 | 1 | 11 | 23 |
| A2 | 7 | 9 | 8 | 7 | 31 |
| A3 | 4 | 8 | 8 | 8 | 28 |
| A4 | 2 | 5 | 6 | 14 | 27 |
| total | 22 | 24 | 23 | 40 | 109 |
+-------+------+------+------+------+-------+
5 rows in set, 1 warning (0.00 sec)
2. 利用SUM(IF()) 生成列 + UNION 生成汇总行,并利用 IFNULL将汇总行标题显示为 Total
mysql> select c1,
-> sum(if(c2='B1',C3,0)) AS B1,
-> sum(if(c2='B2',C3,0)) AS B2,
-> sum(if(c2='B3',C3,0)) AS B3,
-> sum(if(c2='B4',C3,0)) AS B4,SUM(C3) AS TOTAL
-> from tx
-> group by C1
-> UNION
-> SELECT 'TOTAL',sum(if(c2='B1',C3,0)) AS B1,
-> sum(if(c2='B2',C3,0)) AS B2,
-> sum(if(c2='B3',C3,0)) AS B3,
-> sum(if(c2='B4',C3,0)) AS B4,SUM(C3) FROM TX
-> ;
+-------+------+------+------+------+-------+
| c1 | B1 | B2 | B3 | B4 | TOTAL |
+-------+------+------+------+------+-------+
| A1 | 9 | 2 | 1 | 11 | 23 |
| A2 | 7 | 9 | 8 | 7 | 31 |
| A3 | 4 | 8 | 8 | 8 | 28 |
| A4 | 2 | 5 | 6 | 14 | 27 |
| TOTAL | 22 | 24 | 23 | 40 | 109 |
+-------+------+------+------+------+-------+
5 rows in set (0.00 sec)
mysql>
3. 利用SUM(IF()) 生成列,直接生成结果不再利用子查询
mysql> select ifnull(c1,'total'),
-> sum(if(c2='B1',C3,0)) AS B1,
-> sum(if(c2='B2',C3,0)) AS B2,
-> sum(if(c2='B3',C3,0)) AS B3,
-> sum(if(c2='B4',C3,0)) AS B4,SUM(C3) AS TOTAL
-> from tx
-> group by C1 with rollup ;
+--------------------+------+------+------+------+-------+
| ifnull(c1,'total') | B1 | B2 | B3 | B4 | TOTAL |
+--------------------+------+------+------+------+-------+
| A1 | 9 | 2 | 1 | 11 | 23 |
| A2 | 7 | 9 | 8 | 7 | 31 |
| A3 | 4 | 8 | 8 | 8 | 28 |
| A4 | 2 | 5 | 6 | 14 | 27 |
| total | 22 | 24 | 23 | 40 | 109 |
+--------------------+------+------+------+------+-------+
5 rows in set (0.00 sec)
mysql>
4. 动态,适用于列不确定情况,
mysql> SET @EE='';
mysql> SELECT @EE:=CONCAT(@EE,'SUM(IF(C2='',C2,''',',C3,0)) AS ',C2,',') FROM (SELECT DISTINCT C2 FROM TX) A;
mysql> SET @QQ=CONCAT('SELECT ifnull(c1,'total'),',LEFT(@EE,LENGTH(@EE)-1),' ,SUM(C3) AS TOTAL FROM TX GROUP BY C1 WITH ROLLUP');
Query OK, 0 rows affected (0.00 sec)
mysql> PREPARE stmt2 FROM @QQ;
Query OK, 0 rows affected (0.00 sec)
Statement prepared
mysql> EXECUTE stmt2;
+--------------------+------+------+------+------+-------+
| ifnull(c1,'total') | B1 | B2 | B3 | B4 | TOTAL |
+--------------------+------+------+------+------+-------+
| A1 | 9 | 2 | 1 | 11 | 23 |
| A2 | 7 | 9 | 8 | 7 | 31 |
| A3 | 4 | 8 | 8 | 8 | 28 |
| A4 | 2 | 5 | 6 | 14 | 27 |
| total | 22 | 24 | 23 | 40 | 109 |
+--------------------+------+------+------+------+-------+
5 rows in set (0.00 sec)
mysql>
以上均由网友 liangCK , wwwwb , WWWWA , dap570 提供, 再次感谢他们的支持。
其实数据库中也可以用 CASE WHEN / DECODE 代替 IF