join.test 5.1 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210
  1. # 2002 May 24
  2. #
  3. # The author disclaims copyright to this source code. In place of
  4. # a legal notice, here is a blessing:
  5. #
  6. # May you do good and not evil.
  7. # May you find forgiveness for yourself and forgive others.
  8. # May you share freely, never taking more than you give.
  9. #
  10. #***********************************************************************
  11. # This file implements regression tests for SQLite library.
  12. #
  13. # This file implements tests for joins, including outer joins.
  14. #
  15. # $Id: join.test,v 1.2 2002/05/25 00:18:21 drh Exp $
  16. set testdir [file dirname $argv0]
  17. source $testdir/tester.tcl
  18. do_test join-1.1 {
  19. execsql {
  20. CREATE TABLE t1(a,b,c);
  21. INSERT INTO t1 VALUES(1,2,3);
  22. INSERT INTO t1 VALUES(2,3,4);
  23. INSERT INTO t1 VALUES(3,4,5);
  24. SELECT * FROM t1;
  25. }
  26. } {1 2 3 2 3 4 3 4 5}
  27. do_test join-1.2 {
  28. execsql {
  29. CREATE TABLE t2(b,c,d);
  30. INSERT INTO t2 VALUES(1,2,3);
  31. INSERT INTO t2 VALUES(2,3,4);
  32. INSERT INTO t2 VALUES(3,4,5);
  33. SELECT * FROM t2;
  34. }
  35. } {1 2 3 2 3 4 3 4 5}
  36. do_test join-1.3 {
  37. execsql2 {
  38. SELECT * FROM t1 NATURAL JOIN t2;
  39. }
  40. } {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
  41. do_test join-1.3.1 {
  42. execsql2 {
  43. SELECT * FROM t2 NATURAL JOIN t1;
  44. }
  45. } {t2.b 2 t2.c 3 t2.d 4 t1.a 1 t2.b 3 t2.c 4 t2.d 5 t1.a 2}
  46. do_test join-1.4 {
  47. execsql2 {
  48. SELECT * FROM t1 INNER JOIN t2 USING(b,c);
  49. }
  50. } {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
  51. do_test join-1.5 {
  52. execsql2 {
  53. SELECT * FROM t1 INNER JOIN t2 USING(b);
  54. }
  55. } {t1.a 1 t1.b 2 t1.c 3 t2.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.c 4 t2.d 5}
  56. do_test join-1.6 {
  57. execsql2 {
  58. SELECT * FROM t1 INNER JOIN t2 USING(c);
  59. }
  60. } {t1.a 1 t1.b 2 t1.c 3 t2.b 2 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.b 3 t2.d 5}
  61. do_test join-1.7 {
  62. execsql2 {
  63. SELECT * FROM t1 INNER JOIN t2 USING(c,b);
  64. }
  65. } {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5}
  66. do_test join-1.8 {
  67. execsql {
  68. SELECT * FROM t1 NATURAL CROSS JOIN t2;
  69. }
  70. } {1 2 3 4 2 3 4 5}
  71. do_test join-1.9 {
  72. execsql {
  73. SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
  74. }
  75. } {1 2 3 4 2 3 4 5}
  76. do_test join-1.10 {
  77. execsql {
  78. SELECT * FROM t1 NATURAL INNER JOIN t2;
  79. }
  80. } {1 2 3 4 2 3 4 5}
  81. do_test join-1.11 {
  82. execsql {
  83. SELECT * FROM t1 INNER JOIN t2 USING(b,c);
  84. }
  85. } {1 2 3 4 2 3 4 5}
  86. do_test join-1.12 {
  87. execsql {
  88. SELECT * FROM t1 natural inner join t2;
  89. }
  90. } {1 2 3 4 2 3 4 5}
  91. do_test join-1.13 {
  92. execsql2 {
  93. SELECT * FROM t1 NATURAL JOIN
  94. (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3
  95. }
  96. } {t1.a 1 t1.b 2 t1.c 3 t3.d 4 t3.e 5}
  97. do_test join-1.14 {
  98. execsql2 {
  99. SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx'
  100. NATURAL JOIN t1
  101. }
  102. } {tx.c 3 tx.d 4 tx.e 5 t1.a 1 t1.b 2}
  103. do_test join-1.15 {
  104. execsql {
  105. CREATE TABLE t3(c,d,e);
  106. INSERT INTO t3 VALUES(2,3,4);
  107. INSERT INTO t3 VALUES(3,4,5);
  108. INSERT INTO t3 VALUES(4,5,6);
  109. SELECT * FROM t3;
  110. }
  111. } {2 3 4 3 4 5 4 5 6}
  112. do_test join-1.16 {
  113. execsql {
  114. SELECT * FROM t1 natural join t2 natural join t3;
  115. }
  116. } {1 2 3 4 5 2 3 4 5 6}
  117. do_test join-1.17 {
  118. execsql2 {
  119. SELECT * FROM t1 natural join t2 natural join t3;
  120. }
  121. } {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t3.e 5 t1.a 2 t1.b 3 t1.c 4 t2.d 5 t3.e 6}
  122. do_test join-1.18 {
  123. execsql {
  124. CREATE TABLE t4(d,e,f);
  125. INSERT INTO t4 VALUES(2,3,4);
  126. INSERT INTO t4 VALUES(3,4,5);
  127. INSERT INTO t4 VALUES(4,5,6);
  128. SELECT * FROM t4;
  129. }
  130. } {2 3 4 3 4 5 4 5 6}
  131. do_test join-1.19 {
  132. execsql {
  133. SELECT * FROM t1 natural join t2 natural join t4;
  134. }
  135. } {1 2 3 4 5 6}
  136. do_test join-1.19 {
  137. execsql2 {
  138. SELECT * FROM t1 natural join t2 natural join t4;
  139. }
  140. } {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t4.e 5 t4.f 6}
  141. do_test join-1.20 {
  142. execsql {
  143. SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
  144. }
  145. } {1 2 3 4 5}
  146. do_test join-2.1 {
  147. execsql {
  148. SELECT * FROM t1 NATURAL LEFT JOIN t2;
  149. }
  150. } {1 2 3 4 2 3 4 5 3 4 5 {}}
  151. do_test join-2.2 {
  152. execsql {
  153. SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
  154. }
  155. } {1 2 3 {} 2 3 4 1 3 4 5 2}
  156. do_test join-2.3 {
  157. catchsql {
  158. SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
  159. }
  160. } {1 {RIGHT and FULL OUTER JOINs are not currently supported}}
  161. do_test join-3.1 {
  162. catchsql {
  163. SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
  164. }
  165. } {1 {a NATURAL join may not have an ON or USING clause}}
  166. do_test join-3.2 {
  167. catchsql {
  168. SELECT * FROM t1 NATURAL JOIN t2 USING(b);
  169. }
  170. } {1 {a NATURAL join may not have an ON or USING clause}}
  171. do_test join-3.3 {
  172. catchsql {
  173. SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
  174. }
  175. } {1 {cannot have both ON and USING clauses in the same join}}
  176. do_test join-3.4 {
  177. catchsql {
  178. SELECT * FROM t1 JOIN t2 USING(a);
  179. }
  180. } {1 {cannot join using column a - column not present in both tables}}
  181. do_test join-3.5 {
  182. catchsql {
  183. SELECT * FROM t1 USING(a);
  184. }
  185. } {0 {1 2 3 2 3 4 3 4 5}}
  186. do_test join-3.6 {
  187. catchsql {
  188. SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
  189. }
  190. } {1 {no such column: t3.a}}
  191. do_test join-3.7 {
  192. catchsql {
  193. SELECT * FROM t1 INNER OUTER JOIN t2;
  194. }
  195. } {1 {unknown or unsupported join type: INNER OUTER}}
  196. do_test join-3.7 {
  197. catchsql {
  198. SELECT * FROM t1 BOGUS JOIN t2;
  199. }
  200. } {1 {unknown or unsupported join type: BOGUS}}
  201. finish_test