第六章、多表查询.sql 8.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276
  1. #第六章、多表查询
  2. #1、熟悉教学常见的几个表
  3. DESC employees;
  4. DESC departments;
  5. DESC locations;
  6. #查询员工名为'Abel'的人在哪个城市工作?
  7. SELECT *
  8. FROM employees
  9. WHERE last_name = 'Abel';
  10. SELECT *
  11. FROM departments
  12. WHERE department_id = 80;
  13. SELECT *
  14. FROM locations
  15. WHERE location_id = 2500;
  16. #2、出现笛卡尔积的错误
  17. #错误的原因:缺少了多表的连接条件
  18. #错误的实现方式:每个员工都与每个部门匹配了一遍
  19. SELECT employee_id,department_name
  20. FROM employees,departments; #查询出2889条记录
  21. #错误的方式
  22. SELECT employee_id,department_name
  23. FROM employees CROSS JOIN departments; #查询出2889条记录
  24. SELECT *
  25. FROM employees;
  26. SELECT 2889/107
  27. FROM DUAL;
  28. SELECT *
  29. FROM departments;
  30. #3、多表查询的正确方式:需要有连接条件
  31. SELECT employee_id,department_name
  32. FROM employees,departments
  33. #两个表的连接条件
  34. WHERE employees.`department_id` = departments.department_id;
  35. #4、如果查询语句中出现了多个表中都存在的字段,则必须指明此字段所在的表。
  36. SELECT employees.employee_id,departments.department_name,employees.department_id
  37. FROM employees,departments
  38. WHERE employees.`department_id` = departments.`department_id`;
  39. #建议:从SQL优化的角度,建议多表查询时,每个字段前都指明其所在的表
  40. #5、可以给表起别名,在SELECT和WHERE中使用表的别名
  41. SELECT emp.employee_id,dept.department_name,emp.department_id
  42. FROM employees emp,departments dept
  43. WHERE emp.`department_id` = dept.department_id;
  44. #如果给表起了别名,一旦在SELECT或WHERE中使用表名的话,则必须使用表的别名,而不能再使用表的原名。
  45. #如下的操作是错误的:
  46. SELECT emp.employee_id,departments.department_name,emp.department_id
  47. FROM employees emp,departments dept
  48. WHERE emp.`department_id` = departments.department_id;
  49. #6、结论:如果有n个表实现多表的查询,则需要至少n-1个连接条件
  50. #练习:查询员工的employee_id,last_name,department_name,city
  51. SELECT e.employee_id,e.last_name,d.department_name,l.city,e.department_id,l.location_id
  52. FROM employees e,departments d,locations l
  53. WHERE e.`department_id` = d.`department_id` AND d.`location_id` = l.`location_id`;
  54. /*
  55. 演绎式:提出问题1 ---> 解决问题1 ---> 提出问题2 ---> 解决问题2 ...
  56. 归纳式:总 -- 分
  57. */
  58. #7、多表查询的分类
  59. /*
  60. 角度1:等值连接 vs 非等值连接
  61. 角度2:自连接 vs 非自连接
  62. 角度3:内连接 vs 外连接
  63. */
  64. #7.1、等值连接 vs 非等值连接
  65. #非等值连接的例子:
  66. SELECT *
  67. FROM job_grades;
  68. SELECT e.last_name,e.salary,j.grade_level
  69. FROM employees e,job_grades j
  70. #WHERE e.`salary` BETWEEN j.`lowest_sal` AND j.`highest_sal`;
  71. WHERE e.`salary` >= j.`lowest_sal` AND e.`salary` <= j.`highest_sal`;
  72. #7.2、自连接 vs 非自连接
  73. #自连接的例子:
  74. #练习:查询员工id,员工姓名及其管理者的id和姓名
  75. SELECT emp.employee_id,emp.last_name,mgr.employee_id,mgr.last_name
  76. FROM employees emp,employees mgr
  77. WHERE emp.`manager_id` = mgr.`employee_id`;
  78. #7.3、内连接 vs 外连接
  79. #内连接:合并具有同一列的两个以上的表的行,结果集中不包含一个表与另一个表不匹配的行
  80. SELECT employee_id,department_name
  81. FROM employees e,departments d
  82. WHERE e.`department_id` = d.`department_id`; #只有106条记录
  83. #外连接:合并具有同一列的两个以上的表的行,结果集中除了包含一个表与另一个表匹配的行之外,还查询到了左表或右表中不匹配的行
  84. #外连接的分类:左外连接、右外连接、满外连接
  85. #左外连接:两个表在连接过程中除了返回满足连接条件的行以外,还返回左表中不满足条件的行,这种连接称为左外连接。
  86. #右外连接:两个表在连接过程中除了返回满足连接条件的行以外,还返回右表中不满足条件的行,这种连接称为右外连接。
  87. #练习:查询所有的员工的last_name,department_name信息
  88. #题目中包含了“所有的”,所以就可能存在不匹配的数据,因此一定是外连接
  89. SELECT employee_id,department_name
  90. FROM employees e,departments d
  91. WHERE e.`department_id` = d.department_id; #需要使用左外连接
  92. #SQL92语法实现内连接:(上面的写法就是)
  93. #SQL92语法实现外连接:使用+ -----MySQL不支持SQL92语法中外连接的写法!(Oracle支持)
  94. #不支持
  95. SELECT employee_id,department_name
  96. FROM employees e,departments d
  97. WHERE e.`department_id` = d.department_id(+);
  98. #SQL99语法中使用JOIN ...ON的方式实现多表的查询。这种方式也能解决外连接的问题。
  99. #MySQL是支持此种方式的。
  100. #SQL99语法如何实现多表的查询。
  101. #SQL99语法实现内连接:(INNER可以省略)
  102. SELECT last_name,department_name
  103. #FROM employees e INNER JOIN departments d
  104. FROM employees e JOIN departments d
  105. ON e.department_id = d.department_id;
  106. SELECT last_name,department_name,city
  107. FROM employees e JOIN departments d
  108. ON e.department_id = d.department_id
  109. JOIN locations l
  110. ON d.location_id = l.location_id;
  111. #练习:查询所有的员工的last_name,department_name信息
  112. #左外连接:(因为加了LEFT,所以OUTER也可以省略)
  113. SELECT last_name,department_name
  114. #FROM employees e LEFT OUTER JOIN departments d
  115. FROM employees e LEFT JOIN departments d
  116. ON e.department_id = d.department_id;
  117. #右外连接:(因为加了RIGHT,所以OUTER也可以省略)
  118. SELECT last_name,department_name
  119. #FROM employees e RIGHT OUTER JOIN departments d
  120. FROM employees e RIGHT JOIN departments d
  121. ON e.department_id = d.department_id;
  122. #满外连接:MySQL不支持FULL OUTER JOIN的方式(Oracle支持)
  123. SELECT last_name,department_name
  124. FROM employees e FULL OUTER JOIN departments d
  125. ON e.department_id = d.department_id;
  126. #8、UNION和UNION ALL的使用
  127. #UNION:会执行去重的操作
  128. #UNION ALL:不会执行去重的操作
  129. #结论:如果明确知道合并数据后的结果数据不存在重复数据,或者不需要去除重复的
  130. #数据,则尽量使用UNION ALL语句,以提高数据查询的效率。
  131. #9、7种JOIN的实现
  132. #中图:内连接
  133. SELECT employee_id,department_name
  134. FROM employees e JOIN departments d
  135. ON e.department_id = d.department_id;
  136. #左上图:左外连接
  137. SELECT employee_id,department_name
  138. FROM employees e LEFT JOIN departments d
  139. ON e.department_id = d.department_id;
  140. #右上图:右外连接
  141. SELECT employee_id,department_name
  142. FROM employees e RIGHT JOIN departments d
  143. ON e.department_id = d.department_id;
  144. #左中图:
  145. SELECT employee_id,department_name
  146. FROM employees e LEFT JOIN departments d
  147. ON e.department_id = d.department_id
  148. WHERE d.department_id IS NULL;
  149. #右中图
  150. SELECT employee_id,department_name
  151. FROM employees e RIGHT JOIN departments d
  152. ON e.department_id = d.department_id
  153. WHERE e.department_id IS NULL;
  154. #左下图:满外连接
  155. #方式1:左上图 UNION ALL 右中图
  156. SELECT employee_id,department_name
  157. FROM employees e LEFT JOIN departments d
  158. ON e.department_id = d.department_id
  159. UNION ALL
  160. SELECT employee_id,department_name
  161. FROM employees e RIGHT JOIN departments d
  162. ON e.department_id = d.department_id
  163. WHERE e.department_id IS NULL;
  164. #方式2:左中图 UNION ALL 右上图
  165. SELECT employee_id,department_name
  166. FROM employees e LEFT JOIN departments d
  167. ON e.department_id = d.department_id
  168. WHERE d.department_id IS NULL
  169. UNION ALL
  170. SELECT employee_id,department_name
  171. FROM employees e RIGHT JOIN departments d
  172. ON e.department_id = d.department_id;
  173. #右下图:左中图 UNION ALL 右中图
  174. SELECT employee_id,department_name
  175. FROM employees e LEFT JOIN departments d
  176. ON e.department_id = d.department_id
  177. WHERE d.department_id IS NULL
  178. UNION ALL
  179. SELECT employee_id,department_name
  180. FROM employees e RIGHT JOIN departments d
  181. ON e.department_id = d.department_id
  182. WHERE e.department_id IS NULL;
  183. #10、SQL99语法的新特性1:自然连接
  184. SELECT employee_id,last_name,department_name
  185. FROM employees e JOIN departments d
  186. ON e.department_id = d.department_id
  187. AND e.manager_id = d.manager_id;
  188. #NATURAL JOIN:它会帮你自动查询两张连接表中“所有相同的字段”,然后进行“等值连接”
  189. SELECT employee_id,last_name,department_name
  190. FROM employees e NATURAL JOIN departments d;
  191. #11、SQL99语法的新特性2:USING
  192. SELECT employee_id,last_name,department_name
  193. FROM employees e JOIN departments d
  194. ON e.department_id = d.department_id;
  195. SELECT employee_id,last_name,department_name
  196. FROM employees e JOIN departments d
  197. USING (department_id);
  198. #拓展
  199. SELECT last_name,job_title,department_name
  200. FROM employees INNER JOIN departments INNER JOIN jobs
  201. ON employees.department_id = departments.department_id
  202. AND employees.job_id = jobs.job_id;