一文弄懂MYSQL如何列转行

bangongJIAO1@c 发布于 2025-12-01 阅读(2)
目录
  • 一、需求:
  • 二、如何实现
    • 1)首先看我们的静态SQL
    • 2)那么就有人问了,如果我有100门课程不是要写100次名称,这也太麻烦了?
    • 3)这样每次都写一长串sql也很麻烦?
  • 总结

    一、需求:

    有三张表,学生表、成绩表和课程表,我们可以通过连表查询出学生姓名、课程及对应的成绩: 所需表sql

    -- ----------------------------
    -- Table structure for student
    -- ----------------------------
    DROP TABLE IF EXISTS `student`;
    CREATE TABLE `student` (
      `s_id` varchar(20) NOT NULL DEFAULT '',
      `s_name` varchar(20) NOT NULL DEFAULT '',
      `s_birth` varchar(20) NOT NULL DEFAULT '',
      `s_sex` varchar(10) NOT NULL DEFAULT '',
      PRIMARY KEY (`s_id`)
    ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
     
    -- ----------------------------
    -- Records of student
    -- ----------------------------
    INSERT INTO `student` VALUES ('01', '赵雷', '1990-01-01', '男');
    INSERT INTO `student` VALUES ('02', '钱电', '1990-12-21', '男');
    INSERT INTO `student` VALUES ('03', '孙风', '1990-05-20', '男');
    INSERT INTO `student` VALUES ('04', '李云', '1990-08-06', '男');
    INSERT INTO `student` VALUES ('05', '周梅', '1991-12-01', '女');
    INSERT INTO `student` VALUES ('06', '吴兰', '1992-03-01', '女');
    INSERT INTO `student` VALUES ('07', '郑竹', '1989-07-01', '女');
    INSERT INTO `student` VALUES ('08', '王菊', '1990-01-20', '女');
     
    -- ----------------------------
    -- Table structure for course
    -- ----------------------------
    DROP TABLE IF EXISTS `course`;
    CREATE TABLE `course` (
      `c_id` varchar(20) NOT NULL DEFAULT '',
      `c_name` varchar(20) NOT NULL DEFAULT '',
      `t_id` varchar(20) NOT NULL,
      PRIMARY KEY (`c_id`)
    ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
     
    -- ----------------------------
    -- Records of course
    -- ----------------------------
    INSERT INTO `course` VALUES ('01', '语文', '02');
    INSERT INTO `course` VALUES ('02', '数学', '01');
    INSERT INTO `course` VALUES ('03', '英语', '03');
     
    -- ----------------------------
    -- Table structure for score
    -- ----------------------------
    DROP TABLE IF EXISTS `score`;
    CREATE TABLE `score` (
      `s_id` varchar(20) NOT NULL DEFAULT '',
      `c_id` varchar(20) NOT NULL DEFAULT '',
      `s_score` int(3) DEFAULT NULL,
      PRIMARY KEY (`s_id`,`c_id`)
    ) ENGINE=InnoDB DEFAULT CHARSET=utf8;
     
    -- ----------------------------
    -- Records of score
    -- ----------------------------
    INSERT INTO `score` VALUES ('01', '01', '80');
    INSERT INTO `score` VALUES ('01', '02', '90');
    INSERT INTO `score` VALUES ('01', '03', '99');
    INSERT INTO `score` VALUES ('02', '01', '70');
    INSERT INTO `score` VALUES ('02', '02', '60');
    INSERT INTO `score` VALUES ('02', '03', '80');
    INSERT INTO `score` VALUES ('03', '01', '80');
    INSERT INTO `score` VALUES ('03', '02', '80');
    INSERT INTO `score` VALUES ('03', '03', '80');
    INSERT INTO `score` VALUES ('04', '01', '50');
    INSERT INTO `score` VALUES ('04', '02', '30');
    INSERT INTO `score` VALUES ('04', '03', '20');
    INSERT INTO `score` VALUES ('05', '01', '76');
    INSERT INTO `score` VALUES ('05', '02', '87');
    INSERT INTO `score` VALUES ('06', '01', '31');
    INSERT INTO `score` VALUES ('06', '03', '34');
    INSERT INTO `score` VALUES ('07', '02', '89');
    INSERT INTO `score` VALUES ('07', '03', '98');
    SELECT s.s_id,s.s_name,c.c_name,sc.s_score 
    FROM student s 
    LEFT JOIN score sc on sc.s_id = s.s_id 
    LEFT JOIN course c on c.c_id = sc.c_id

    一文弄懂MYSQL如何列转行

    好的,现在呢我们要把课程名称呢变成横行呢?

    一文弄懂MYSQL如何列转行

    二、如何实现

    1)首先看我们的静态SQL

    关联成绩表课程表查询学生各科课程成绩

    SELECT s.s_id,s.s_name,c.c_name,sc.s_score
    FROM student s
    LEFT JOIN score sc on sc.s_id=s.s_id
    LEFT JOIN course c on c.c_id = sc.c_id;

    IF(s1,s2,s3)表达式,类似三木运算符取值,s1值为真取s2值,假取s3个值,最后可得到某一科成绩

    SELECT  p.s_id,p.s_name, p.c_name,p.c_name = '数学',
    IF(p.c_name = '数学',p.c_name,NULL)c_name,IF(p.c_name = '数学',p.s_score,NULL)s_score
    FROM (
    	SELECT s.s_id,s.s_name,c.c_name,sc.s_score
    	FROM student s
    	LEFT JOIN score sc on sc.s_id=s.s_id
    	LEFT JOIN course c on c.c_id = sc.c_id	)p;

    然后我们分组且用MAX函数获取每个学生的数学课程的成绩,替换这一课的字段名称

    SELECT  p.s_id,
            p.s_name, 
            MAX(IF(p.c_name = '数学', p.s_score, NULL)) AS 数学
    FROM (
    	SELECT s.s_id,s.s_name,c.c_name,sc.s_score
    	FROM student s
    	LEFT JOIN score sc on sc.s_id=s.s_id
    	LEFT JOIN course c on c.c_id = sc.c_id	)p
    GROUP BY p.s_id;

    获取所有人各科成绩

    SELECT  p.s_id,
            p.s_name, 
            MAX(IF(p.c_name = '数学', p.s_score, NULL)) AS 数学,
            MAX(IF(p.c_name = '语文', p.s_score, NULL)) AS 语文,
            MAX(IF(p.c_name = '英语', p.s_score, NULL)) AS 英语
    FROM (
    	SELECT s.s_id,s.s_name,c.c_name,sc.s_score
    	FROM student s
    	LEFT JOIN score sc on sc.s_id=s.s_id
    	LEFT JOIN course c on c.c_id = sc.c_id	)p
    GROUP BY p.s_id;

    一文弄懂MYSQL如何列转行

    2)那么就有人问了,如果我有100门课程不是要写100次名称,这也太麻烦了?

    接下来请看动态SQL

    我们的动态sql是拼接实现的, 主要就是拼接我们的课程成绩那一句, 所以要先看一下CONCAT函数拼接课程语句

    SELECT c_name,CONCAT( 'MAX(IF(p.c_name = ''', c_name, ''', c.s_score, NULL)) AS ', c_name ) FROM course c;

    是的,结果就是上面要的MAX函数

    一文弄懂MYSQL如何列转行

    然后我么可以用GROUP_CONCAT()函数把这些内容拼接成一句

    SELECT GROUP_CONCAT(DISTINCT c_name,CONCAT( 'MAX(IF(p.c_name = ''', c_name, ''', c.s_score, NULL)) AS ', c_name )) FROM course c;
    

    一文弄懂MYSQL如何列转行

    接下来,拼接sql实现需求

    -- 1.定义一个sql变量
    SET @sql = NULL;
     
    -- 2.把我们的查询课程的sql赋给变量
    SELECT GROUP_CONCAT(DISTINCT CONCAT('MAX(IF(p.c_name = ''',c_name,''', p.s_score, NULL)) AS ',c_name)) INTO @sql
    FROM course;
     
    -- 3.拼接sql
    SET @sql = CONCAT('SELECT  p.s_id, p.s_name, ', @sql ,'
    			FROM (SELECT s.s_id,s.s_name,c.c_name,sc.s_score 
    			FROM student s 
    			LEFT JOIN score sc on sc.s_id=s.s_id 
    			LEFT JOIN course c on c.c_id = sc.c_id)p 
    			GROUP BY p.s_id');
     
    -- 预处理语句 
    PREPARE stmt FROM @sql;
    -- 执行
    EXECUTE stmt;
    -- 销毁
    DEALLOCATE PREPARE stmt;

    一文弄懂MYSQL如何列转行

    3)这样每次都写一长串sql也很麻烦?

    好的 那么我们来封装成存储过程

    -- 1、创建无参存储过程
    delimiter $$
    CREATE PROCEDURE getStudentRow()
    BEGIN
        ------把要执行的sql放在这里就可以了
    		SET @sql = NULL;
    		SELECT
            GROUP_CONCAT(DISTINCT CONCAT('MAX(IF(p.c_name = ''',c_name,''', p.s_score, NULL)) AS ',c_name)) 
            INTO @sql FROM course;
        SET @sql = CONCAT('SELECT  p.s_id, p.s_name, ', @sql ,'
        	FROM (SELECT s.s_id,s.s_name,c.c_name,sc.s_score 
        	FROM student s 
        	LEFT JOIN score sc on sc.s_id=s.s_id 
        	LEFT JOIN course c on c.c_id = sc.c_id)p 
        	GROUP BY p.s_id');
        PREPARE stmt FROM @sql;
        EXECUTE stmt;
        DEALLOCATE PREPARE stmt;
        ------把要执行的sql放在这里就可以了
    END$$;
    delimiter;
     
    -- 查询存储过程
    SHOW PROCEDURE STATUS;
     
    -- 调用
    CALL getStudentRow();

    一文弄懂MYSQL如何列转行

    这样每次直接调用就可以了?

    总结