DROPTABLEIFEXISTS tb_score;CREATETABLEtb_score( id INT(11) NOT NULL auto_increment, userid VARCHAR(20) NOT NULL COMMENT '用户id',subjectVARCHAR(20) COMMENT '科目', score DOUBLE COMMENT '成绩',PRIMARY KEY(id))ENGINE = INNODB DEFAULT CHARSET = utf8;
插入数据:
INSERT INTO tb_score(userid,subject,score) VALUES ('001','语文',90);INSERT INTO tb_score(userid,subject,score) VALUES ('001','数学',92);INSERT INTO tb_score(userid,subject,score) VALUES ('001','英语',80);INSERT INTO tb_score(userid,subject,score) VALUES ('002','语文',88);INSERT INTO tb_score(userid,subject,score) VALUES ('002','数学',90);INSERT INTO tb_score(userid,subject,score) VALUES ('002','英语',75.5);INSERT INTO tb_score(userid,subject,score) VALUES ('003','语文',70);INSERT INTO tb_score(userid,subject,score) VALUES ('003','数学',85);INSERT INTO tb_score(userid,subject,score) VALUES ('003','英语',90);INSERT INTO tb_score(userid,subject,score) VALUES ('003','政治',82);
SELECT userid,SUM(CASE`subject`WHEN'语文'THEN score ELSE0END) as'语文',SUM(CASE`subject`WHEN'数学'THEN score ELSE0END) as'数学',SUM(CASE`subject`WHEN'英语'THEN score ELSE0END) as'英语',SUM(CASE`subject`WHEN'政治'THEN score ELSE0END) as'政治'FROM tb_score GROUP BY userid
1.2 使用IF() 进行行转列
SELECT userid,SUM(IF(`subject`='语文',score,0)) as'语文',SUM(IF(`subject`='数学',score,0)) as'数学',SUM(IF(`subject`='英语',score,0)) as'英语',SUM(IF(`subject`='政治',score,0)) as'政治'FROM tb_score GROUP BY userid
1.3 利用SUM(IF()) 生成列 + WITH ROLLUP 生成汇总行,并利用 IFNULL将汇总行标题显示为Total
SELECTIFNULL(userid,'total') AS userid,SUM(IF(`subject`='语文',score,0)) AS 语文,SUM(IF(`subject`='数学',score,0)) AS 数学,SUM(IF(`subject`='英语',score,0)) AS 英语,SUM(IF(`subject`='政治',score,0)) AS 政治,SUM(IF(`subject`='total',score,0)) AS totalFROM(SELECT userid,IFNULL(`subject`,'total') AS`subject`,SUM(score) AS scoreFROM tb_scoreGROUP BY userid,`subject`WITHROLLUPHAVING userid IS NOT NULL)AS A GROUP BY useridWITHROLLUP;
运行结果:
1.4 利用SUM(IF()) 生成列 + UNION 生成汇总行,并利用 IFNULL将汇总行标题显示为 Total
SELECT userid,SUM(IF(`subject`='语文',score,0)) AS 语文,SUM(IF(`subject`='数学',score,0)) AS 数学,SUM(IF(`subject`='英语',score,0)) AS 英语,SUM(IF(`subject`='政治',score,0)) AS 政治,SUM(score) AS TOTAL FROM tb_scoreGROUP BY useridUNIONSELECT'TOTAL',SUM(IF(`subject`='语文',score,0)) AS 语文,SUM(IF(`subject`='数学',score,0)) AS 数学,SUM(IF(`subject`='英语',score,0)) AS 英语,SUM(IF(`subject`='政治',score,0)) AS 政治,SUM(score) FROM tb_score
运行结果:
1.5 利用SUM(IF()) 生成列,直接生成结果不再利用子查询
SELECTIFNULL(userid,'TOTAL') AS userid,SUM(IF(`subject`='语文',score,0)) AS 语文,SUM(IF(`subject`='数学',score,0)) AS 数学,SUM(IF(`subject`='英语',score,0)) AS 英语,SUM(IF(`subject`='政治',score,0)) AS 政治,SUM(score) AS TOTAL FROM tb_scoreGROUP BY userid WITHROLLUP;
运行结果:
1.6 动态,适用于列不确定情况
SET @EE='';select @EE :=CONCAT(@EE,'sum(if(subject= \'',subject,'\',score,0)) as ',subject, ',') AS aa FROM (SELECT DISTINCTsubjectFROM tb_score) A ;SET @QQ =CONCAT('select ifnull(userid,\'TOTAL\')as userid,',@EE,' sum(score) as TOTAL from tb_score group by userid WITH ROLLUP');-- SELECT @QQ;PREPARE stmt FROM @QQ;EXECUTE stmt;DEALLOCATE PREPARE stmt;
运行结果:
1.7 合并字段显示:利用group_concat()
SELECT userid,GROUP_CONCAT(`subject`,":",score)AS 成绩 FROM tb_scoreGROUP BY userid
INSERT INTO tb_score1(userid,cn_score,math_score,en_score,po_score) VALUES ('001',90,92,80,0);INSERT INTO tb_score1(userid,cn_score,math_score,en_score,po_score) VALUES ('002',88,90,75.5,0);INSERT INTO tb_score1(userid,cn_score,math_score,en_score,po_score) VALUES ('003',70,85,90,82);
查询数据表中的内容(即转换前的结果):
SELECT*FROM tb_score1
转换后:
本质是将userid的每个科目分数分散成一条记录显示出来。
直接上SQL:
SELECT userid,'语文'AS course,cn_score AS score FROM tb_score1UNION ALLSELECT userid,'数学'AS course,math_score AS score FROM tb_score1UNION ALLSELECT userid,'英语'AS course,en_score AS score FROM tb_score1UNION ALLSELECT userid,'政治'AS course,po_score AS score FROM tb_score1ORDER BY userid