多表查询思路

数据准备

  1. create table dep(
  2. id int primary key auto_increment,
  3. name varchar(32)
  4. );
  5. create table emp(
  6. id int primary key auto_increment,
  7. name varchar(32),
  8. gender enum('male','female','others') default 'male',
  9. age int,
  10. dep_id int
  11. );
  12. insert into dep values(200,'技术'),(201,'人力资源'),(202,'销售'),(203,'运营'),(205,'安保');
  13. insert into emp(name,age,dep_id) values('kevin',18,200),('tony',28,201),('oscar',38,201),('jerry',29,202),('jason',39,203),('jack',48,204);

子查询

将一条SQL语句的查询结果加括号当做另外一条SQL语句的查询条件

题目:获取kevin所在的部门名称

思路:先获取kevin的部门编号,再将结果加括号作为查询条件

  1. select name from dep where id =(select dep_id from emp where name='kevin');

连表查询

先将多张表拼接到一起 形成一张大表 然后基于单表查询获取数据

关键字:

  • inner join(内连接):只连接两张表中有对应关系的数据
  1. select * from emp inner join dep on emp.dep_id=dep.id;
  • left join(左连接):以左表为基准 展示所有的数据 没有对应项则用NULL填充
  1. select * from emp left join dep on emp.dep_id=dep.id;
  • right join(右连接):以右表为基准 展示所有的数据 没有对应项则用NULL填充
  1. select * from emp right join dep on emp.dep_id=dep.id;
  • union(全连接):左右两表数据全部展示 没有对应项则用NULL填充
  1. select * from emp left join dep on emp.dep_id=dep.id
  2. union
  3. select * from emp right join dep on emp.dep_id=dep.id;

题目:获取kevin所在的部门名称

  1. select name,dep.name from emp inner join dep on emp.dep_id= dep.id where emp.name ='kevin';

多表查询练习题

数据准备

  1. /*
  2. 数据导入:
  3. Navicat Premium Data Transfer
  4. Source Server : localhost
  5. Source Server Type : MySQL
  6. Source Server Version : 50624
  7. Source Host : localhost
  8. Source Database : sqlexam
  9. Target Server Type : MySQL
  10. Target Server Version : 50624
  11. File Encoding : utf-8
  12. Date: 10/21/2016 06:46:46 AM
  13. */
  14. SET NAMES utf8;
  15. SET FOREIGN_KEY_CHECKS = 0;
  16. -- ----------------------------
  17. -- Table structure for `class`
  18. -- ----------------------------
  19. DROP TABLE IF EXISTS `class`;
  20. CREATE TABLE `class` (
  21. `cid` int(11) NOT NULL AUTO_INCREMENT,
  22. `caption` varchar(32) NOT NULL,
  23. PRIMARY KEY (`cid`)
  24. ) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8;
  25. -- ----------------------------
  26. -- Records of `class`
  27. -- ----------------------------
  28. BEGIN;
  29. INSERT INTO `class` VALUES ('1', '三年二班'), ('2', '三年三班'), ('3', '一年二班'), ('4', '二年九班');
  30. COMMIT;
  31. -- ----------------------------
  32. -- Table structure for `course`
  33. -- ----------------------------
  34. DROP TABLE IF EXISTS `course`;
  35. CREATE TABLE `course` (
  36. `cid` int(11) NOT NULL AUTO_INCREMENT,
  37. `cname` varchar(32) NOT NULL,
  38. `teacher_id` int(11) NOT NULL,
  39. PRIMARY KEY (`cid`),
  40. KEY `fk_course_teacher` (`teacher_id`),
  41. CONSTRAINT `fk_course_teacher` FOREIGN KEY (`teacher_id`) REFERENCES `teacher` (`tid`)
  42. ) ENGINE=InnoDB AUTO_INCREMENT=5 DEFAULT CHARSET=utf8;
  43. -- ----------------------------
  44. -- Records of `course`
  45. -- ----------------------------
  46. BEGIN;
  47. INSERT INTO `course` VALUES ('1', '生物', '1'), ('2', '物理', '2'), ('3', '体育', '3'), ('4', '美术', '2');
  48. COMMIT;
  49. -- ----------------------------
  50. -- Table structure for `score`
  51. -- ----------------------------
  52. DROP TABLE IF EXISTS `score`;
  53. CREATE TABLE `score` (
  54. `sid` int(11) NOT NULL AUTO_INCREMENT,
  55. `student_id` int(11) NOT NULL,
  56. `course_id` int(11) NOT NULL,
  57. `num` int(11) NOT NULL,
  58. PRIMARY KEY (`sid`),
  59. KEY `fk_score_student` (`student_id`),
  60. KEY `fk_score_course` (`course_id`),
  61. CONSTRAINT `fk_score_course` FOREIGN KEY (`course_id`) REFERENCES `course` (`cid`),
  62. CONSTRAINT `fk_score_student` FOREIGN KEY (`student_id`) REFERENCES `student` (`sid`)
  63. ) ENGINE=InnoDB AUTO_INCREMENT=53 DEFAULT CHARSET=utf8;
  64. -- ----------------------------
  65. -- Records of `score`
  66. -- ----------------------------
  67. BEGIN;
  68. INSERT INTO `score` VALUES ('1', '1', '1', '10'), ('2', '1', '2', '9'), ('5', '1', '4', '66'), ('6', '2', '1', '8'), ('8', '2', '3', '68'), ('9', '2', '4', '99'), ('10', '3', '1', '77'), ('11', '3', '2', '66'), ('12', '3', '3', '87'), ('13', '3', '4', '99'), ('14', '4', '1', '79'), ('15', '4', '2', '11'), ('16', '4', '3', '67'), ('17', '4', '4', '100'), ('18', '5', '1', '79'), ('19', '5', '2', '11'), ('20', '5', '3', '67'), ('21', '5', '4', '100'), ('22', '6', '1', '9'), ('23', '6', '2', '100'), ('24', '6', '3', '67'), ('25', '6', '4', '100'), ('26', '7', '1', '9'), ('27', '7', '2', '100'), ('28', '7', '3', '67'), ('29', '7', '4', '88'), ('30', '8', '1', '9'), ('31', '8', '2', '100'), ('32', '8', '3', '67'), ('33', '8', '4', '88'), ('34', '9', '1', '91'), ('35', '9', '2', '88'), ('36', '9', '3', '67'), ('37', '9', '4', '22'), ('38', '10', '1', '90'), ('39', '10', '2', '77'), ('40', '10', '3', '43'), ('41', '10', '4', '87'), ('42', '11', '1', '90'), ('43', '11', '2', '77'), ('44', '11', '3', '43'), ('45', '11', '4', '87'), ('46', '12', '1', '90'), ('47', '12', '2', '77'), ('48', '12', '3', '43'), ('49', '12', '4', '87'), ('52', '13', '3', '87');
  69. COMMIT;
  70. -- ----------------------------
  71. -- Table structure for `student`
  72. -- ----------------------------
  73. DROP TABLE IF EXISTS `student`;
  74. CREATE TABLE `student` (
  75. `sid` int(11) NOT NULL AUTO_INCREMENT,
  76. `gender` char(1) NOT NULL,
  77. `class_id` int(11) NOT NULL,
  78. `sname` varchar(32) NOT NULL,
  79. PRIMARY KEY (`sid`),
  80. KEY `fk_class` (`class_id`),
  81. CONSTRAINT `fk_class` FOREIGN KEY (`class_id`) REFERENCES `class` (`cid`)
  82. ) ENGINE=InnoDB AUTO_INCREMENT=17 DEFAULT CHARSET=utf8;
  83. -- ----------------------------
  84. -- Records of `student`
  85. -- ----------------------------
  86. BEGIN;
  87. INSERT INTO `student` VALUES ('1', '男', '1', '理解'), ('2', '女', '1', '钢蛋'), ('3', '男', '1', '张三'), ('4', '男', '1', '张一'), ('5', '女', '1', '张二'), ('6', '男', '1', '张四'), ('7', '女', '2', '铁锤'), ('8', '男', '2', '李三'), ('9', '男', '2', '李一'), ('10', '女', '2', '李二'), ('11', '男', '2', '李四'), ('12', '女', '3', '如花'), ('13', '男', '3', '刘三'), ('14', '男', '3', '刘一'), ('15', '女', '3', '刘二'), ('16', '男', '3', '刘四');
  88. COMMIT;
  89. -- ----------------------------
  90. -- Table structure for `teacher`
  91. -- ----------------------------
  92. DROP TABLE IF EXISTS `teacher`;
  93. CREATE TABLE `teacher` (
  94. `tid` int(11) NOT NULL AUTO_INCREMENT,
  95. `tname` varchar(32) NOT NULL,
  96. PRIMARY KEY (`tid`)
  97. ) ENGINE=InnoDB AUTO_INCREMENT=6 DEFAULT CHARSET=utf8;
  98. -- ----------------------------
  99. -- Records of `teacher`
  100. -- ----------------------------
  101. BEGIN;
  102. INSERT INTO `teacher` VALUES ('1', '张磊老师'), ('2', '李平老师'), ('3', '刘海燕老师'), ('4', '朱云海老师'), ('5', '李杰老师');
  103. COMMIT;
  104. SET FOREIGN_KEY_CHECKS = 1;

MySQL多表查询 - 图1

1、查询所有的课程的名称以及对应的任课老师姓名

  1. SELECT
  2. course.cname,
  3. teacher.tname
  4. FROM
  5. course
  6. INNER JOIN teacher ON course.teacher_id = teacher.tid;

2、查询平均成绩大于八十分的同学的姓名和平均成绩

  1. SELECT
  2. student.sname,
  3. t1.avg_num
  4. FROM
  5. student
  6. INNER JOIN(SELECT student_id, avg( num ) AS avg_num FROM score GROUP BY score.student_id HAVING avg_num > 80) AS t1 ON student.sid = t1.student_id;

3、查询没有报李平老师课的学生姓名

  1. SELECT
  2. sname
  3. FROM
  4. student
  5. WHERE
  6. sid NOT IN ( SELECT DISTINCT student_id FROM score WHERE course_id IN ( SELECT cid FROM course WHERE teacher_id = ( SELECT tid FROM teacher WHERE tname = '李平老师' ) ) );

4、查询同时选修物理课程和体育课程的学生姓名

  1. SELECT
  2. sname
  3. FROM
  4. student
  5. WHERE
  6. sid IN (
  7. SELECT
  8. student_id
  9. FROM
  10. score
  11. WHERE
  12. course_id IN ( SELECT cid FROM course WHERE cname IN ( '物理', '体育' ) )
  13. GROUP BY
  14. student_id
  15. HAVING
  16. count( course_id ) = 1
  17. );

5、查询挂科超过两门(包括两门)的学生姓名和班级

  1. SELECT
  2. student.sname,
  3. class.caption
  4. FROM
  5. class
  6. INNER JOIN student ON class.cid = student.class_id
  7. WHERE
  8. student.sid IN ( SELECT student_id FROM score WHERE num < 60 GROUP BY student_id HAVING count( course_id ) >= 2 );

6.查询在所有选修了李平老师课程的学生中,这些课程(李平老师的课程,不是所有课程)平均成绩最高的学生姓名

  1. SELECT
  2. sname
  3. FROM
  4. student
  5. WHERE
  6. sid =(
  7. SELECT
  8. student_id
  9. FROM
  10. score
  11. WHERE
  12. course_id IN (
  13. SELECT
  14. cid
  15. FROM
  16. course
  17. WHERE
  18. teacher_id = ( SELECT tid FROM teacher WHERE tname = '李平老师' ))
  19. GROUP BY
  20. student_id
  21. ORDER BY
  22. avg( num ) DESC
  23. LIMIT 1
  24. );