select4.test 8.5 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380
  1. # 2001 September 15
  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. The
  12. # focus of this file is testing UNION, INTERSECT and EXCEPT operators
  13. # in SELECT statements.
  14. #
  15. # $Id: select4.test,v 1.10 2002/06/02 16:09:03 drh Exp $
  16. set testdir [file dirname $argv0]
  17. source $testdir/tester.tcl
  18. # Build some test data
  19. #
  20. set fd [open data1.txt w]
  21. for {set i 1} {$i<32} {incr i} {
  22. for {set j 0} {pow(2,$j)<$i} {incr j} {}
  23. puts $fd "$i\t$j"
  24. }
  25. close $fd
  26. execsql {
  27. CREATE TABLE t1(n int, log int);
  28. COPY t1 FROM 'data1.txt'
  29. }
  30. file delete data1.txt
  31. do_test select4-1.0 {
  32. execsql {SELECT DISTINCT log FROM t1 ORDER BY log}
  33. } {0 1 2 3 4 5}
  34. # Union All operator
  35. #
  36. do_test select4-1.1a {
  37. lsort [execsql {SELECT DISTINCT log FROM t1}]
  38. } {0 1 2 3 4 5}
  39. do_test select4-1.1b {
  40. lsort [execsql {SELECT n FROM t1 WHERE log=3}]
  41. } {5 6 7 8}
  42. do_test select4-1.1c {
  43. execsql {
  44. SELECT DISTINCT log FROM t1
  45. UNION ALL
  46. SELECT n FROM t1 WHERE log=3
  47. ORDER BY log;
  48. }
  49. } {0 1 2 3 4 5 5 6 7 8}
  50. do_test select4-1.2 {
  51. execsql {
  52. SELECT log FROM t1 WHERE n IN
  53. (SELECT DISTINCT log FROM t1 UNION ALL
  54. SELECT n FROM t1 WHERE log=3)
  55. ORDER BY log;
  56. }
  57. } {0 1 2 2 3 3 3 3}
  58. do_test select4-1.3 {
  59. set v [catch {execsql {
  60. SELECT DISTINCT log FROM t1 ORDER BY log
  61. UNION ALL
  62. SELECT n FROM t1 WHERE log=3
  63. ORDER BY log;
  64. }} msg]
  65. lappend v $msg
  66. } {1 {ORDER BY clause should come after UNION ALL not before}}
  67. # Union operator
  68. #
  69. do_test select4-2.1 {
  70. execsql {
  71. SELECT DISTINCT log FROM t1
  72. UNION
  73. SELECT n FROM t1 WHERE log=3
  74. ORDER BY log;
  75. }
  76. } {0 1 2 3 4 5 6 7 8}
  77. do_test select4-2.2 {
  78. execsql {
  79. SELECT log FROM t1 WHERE n IN
  80. (SELECT DISTINCT log FROM t1 UNION
  81. SELECT n FROM t1 WHERE log=3)
  82. ORDER BY log;
  83. }
  84. } {0 1 2 2 3 3 3 3}
  85. do_test select4-2.3 {
  86. set v [catch {execsql {
  87. SELECT DISTINCT log FROM t1 ORDER BY log
  88. UNION
  89. SELECT n FROM t1 WHERE log=3
  90. ORDER BY log;
  91. }} msg]
  92. lappend v $msg
  93. } {1 {ORDER BY clause should come after UNION not before}}
  94. # Except operator
  95. #
  96. do_test select4-3.1 {
  97. execsql {
  98. SELECT DISTINCT log FROM t1
  99. EXCEPT
  100. SELECT n FROM t1 WHERE log=3
  101. ORDER BY log;
  102. }
  103. } {0 1 2 3 4}
  104. do_test select4-3.2 {
  105. execsql {
  106. SELECT log FROM t1 WHERE n IN
  107. (SELECT DISTINCT log FROM t1 EXCEPT
  108. SELECT n FROM t1 WHERE log=3)
  109. ORDER BY log;
  110. }
  111. } {0 1 2 2}
  112. do_test select4-3.3 {
  113. set v [catch {execsql {
  114. SELECT DISTINCT log FROM t1 ORDER BY log
  115. EXCEPT
  116. SELECT n FROM t1 WHERE log=3
  117. ORDER BY log;
  118. }} msg]
  119. lappend v $msg
  120. } {1 {ORDER BY clause should come after EXCEPT not before}}
  121. # Intersect operator
  122. #
  123. do_test select4-4.1 {
  124. execsql {
  125. SELECT DISTINCT log FROM t1
  126. INTERSECT
  127. SELECT n FROM t1 WHERE log=3
  128. ORDER BY log;
  129. }
  130. } {5}
  131. do_test select4-4.2 {
  132. execsql {
  133. SELECT log FROM t1 WHERE n IN
  134. (SELECT DISTINCT log FROM t1 INTERSECT
  135. SELECT n FROM t1 WHERE log=3)
  136. ORDER BY log;
  137. }
  138. } {3}
  139. do_test select4-4.3 {
  140. set v [catch {execsql {
  141. SELECT DISTINCT log FROM t1 ORDER BY log
  142. INTERSECT
  143. SELECT n FROM t1 WHERE log=3
  144. ORDER BY log;
  145. }} msg]
  146. lappend v $msg
  147. } {1 {ORDER BY clause should come after INTERSECT not before}}
  148. # Various error messages while processing UNION or INTERSECT
  149. #
  150. do_test select4-5.1 {
  151. set v [catch {execsql {
  152. SELECT DISTINCT log FROM t2
  153. UNION ALL
  154. SELECT n FROM t1 WHERE log=3
  155. ORDER BY log;
  156. }} msg]
  157. lappend v $msg
  158. } {1 {no such table: t2}}
  159. do_test select4-5.2 {
  160. set v [catch {execsql {
  161. SELECT DISTINCT log AS "xyzzy" FROM t1
  162. UNION ALL
  163. SELECT n FROM t1 WHERE log=3
  164. ORDER BY xyzzy;
  165. }} msg]
  166. lappend v $msg
  167. } {0 {0 1 2 3 4 5 5 6 7 8}}
  168. do_test select4-5.2b {
  169. set v [catch {execsql {
  170. SELECT DISTINCT log AS xyzzy FROM t1
  171. UNION ALL
  172. SELECT n FROM t1 WHERE log=3
  173. ORDER BY 'xyzzy';
  174. }} msg]
  175. lappend v $msg
  176. } {0 {0 1 2 3 4 5 5 6 7 8}}
  177. do_test select4-5.2c {
  178. set v [catch {execsql {
  179. SELECT DISTINCT log FROM t1
  180. UNION ALL
  181. SELECT n FROM t1 WHERE log=3
  182. ORDER BY 'xyzzy';
  183. }} msg]
  184. lappend v $msg
  185. } {1 {ORDER BY term number 1 does not match any result column}}
  186. do_test select4-5.2d {
  187. set v [catch {execsql {
  188. SELECT DISTINCT log FROM t1
  189. INTERSECT
  190. SELECT n FROM t1 WHERE log=3
  191. ORDER BY 'xyzzy';
  192. }} msg]
  193. lappend v $msg
  194. } {1 {ORDER BY term number 1 does not match any result column}}
  195. do_test select4-5.2e {
  196. set v [catch {execsql {
  197. SELECT DISTINCT log FROM t1
  198. UNION ALL
  199. SELECT n FROM t1 WHERE log=3
  200. ORDER BY n;
  201. }} msg]
  202. lappend v $msg
  203. } {0 {0 1 2 3 4 5 5 6 7 8}}
  204. do_test select4-5.2f {
  205. catchsql {
  206. SELECT DISTINCT log FROM t1
  207. UNION ALL
  208. SELECT n FROM t1 WHERE log=3
  209. ORDER BY log;
  210. }
  211. } {0 {0 1 2 3 4 5 5 6 7 8}}
  212. do_test select4-5.2g {
  213. catchsql {
  214. SELECT DISTINCT log FROM t1
  215. UNION ALL
  216. SELECT n FROM t1 WHERE log=3
  217. ORDER BY 1;
  218. }
  219. } {0 {0 1 2 3 4 5 5 6 7 8}}
  220. do_test select4-5.2h {
  221. catchsql {
  222. SELECT DISTINCT log FROM t1
  223. UNION ALL
  224. SELECT n FROM t1 WHERE log=3
  225. ORDER BY 2;
  226. }
  227. } {1 {ORDER BY position 2 should be between 1 and 1}}
  228. do_test select4-5.2i {
  229. catchsql {
  230. SELECT DISTINCT 1, log FROM t1
  231. UNION ALL
  232. SELECT 2, n FROM t1 WHERE log=3
  233. ORDER BY 2, 1;
  234. }
  235. } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
  236. do_test select4-5.2j {
  237. catchsql {
  238. SELECT DISTINCT 1, log FROM t1
  239. UNION ALL
  240. SELECT 2, n FROM t1 WHERE log=3
  241. ORDER BY 1, 2 DESC;
  242. }
  243. } {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}}
  244. do_test select4-5.2k {
  245. catchsql {
  246. SELECT DISTINCT 1, log FROM t1
  247. UNION ALL
  248. SELECT 2, n FROM t1 WHERE log=3
  249. ORDER BY n, 1;
  250. }
  251. } {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}}
  252. do_test select4-5.3 {
  253. set v [catch {execsql {
  254. SELECT DISTINCT log, n FROM t1
  255. UNION ALL
  256. SELECT n FROM t1 WHERE log=3
  257. ORDER BY log;
  258. }} msg]
  259. lappend v $msg
  260. } {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}}
  261. do_test select4-5.4 {
  262. set v [catch {execsql {
  263. SELECT log FROM t1 WHERE n=2
  264. UNION ALL
  265. SELECT log FROM t1 WHERE n=3
  266. UNION ALL
  267. SELECT log FROM t1 WHERE n=4
  268. UNION ALL
  269. SELECT log FROM t1 WHERE n=5
  270. ORDER BY log;
  271. }} msg]
  272. lappend v $msg
  273. } {0 {1 2 2 3}}
  274. do_test select4-6.1 {
  275. execsql {
  276. SELECT log, count(*) as cnt FROM t1 GROUP BY log
  277. UNION
  278. SELECT log, n FROM t1 WHERE n=7
  279. ORDER BY cnt, log;
  280. }
  281. } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
  282. do_test select4-6.2 {
  283. execsql {
  284. SELECT log, count(*) FROM t1 GROUP BY log
  285. UNION
  286. SELECT log, n FROM t1 WHERE n=7
  287. ORDER BY count(*), log;
  288. }
  289. } {0 1 1 1 2 2 3 4 3 7 4 8 5 15}
  290. # NULLs are indistinct for the UNION operator.
  291. # Make sure the UNION operator recognizes this
  292. #
  293. do_test select4-6.3 {
  294. execsql {
  295. SELECT NULL UNION SELECT NULL UNION
  296. SELECT 1 UNION SELECT 2 AS 'x'
  297. ORDER BY x;
  298. }
  299. } {{} 1 2}
  300. do_test select4-6.3.1 {
  301. execsql {
  302. SELECT NULL UNION ALL SELECT NULL UNION ALL
  303. SELECT 1 UNION ALL SELECT 2 AS 'x'
  304. ORDER BY x;
  305. }
  306. } {{} {} 1 2}
  307. # Make sure the DISTINCT keyword treats NULLs as indistinct.
  308. #
  309. do_test select4-6.4 {
  310. execsql {
  311. SELECT * FROM (
  312. SELECT NULL, 1 UNION ALL SELECT NULL, 1
  313. );
  314. }
  315. } {{} 1 {} 1}
  316. do_test select4-6.5 {
  317. execsql {
  318. SELECT DISTINCT * FROM (
  319. SELECT NULL, 1 UNION ALL SELECT NULL, 1
  320. );
  321. }
  322. } {{} 1}
  323. do_test select4-6.6 {
  324. execsql {
  325. SELECT DISTINCT * FROM (
  326. SELECT 1,2 UNION ALL SELECT 1,2
  327. );
  328. }
  329. } {1 2}
  330. # Test distinctness of NULL in other ways.
  331. #
  332. do_test select4-6.7 {
  333. execsql {
  334. SELECT NULL EXCEPT SELECT NULL
  335. }
  336. } {}
  337. # Make sure column names are correct when a compound select appears as
  338. # an expression in the WHERE clause.
  339. #
  340. do_test select4-7.1 {
  341. execsql {
  342. CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log;
  343. SELECT * FROM t2 ORDER BY x;
  344. }
  345. } {0 1 1 1 2 2 3 4 4 8 5 15}
  346. do_test select4-7.2 {
  347. execsql2 {
  348. SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2)
  349. ORDER BY n
  350. }
  351. } {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3}
  352. do_test select4-7.3 {
  353. execsql2 {
  354. SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2)
  355. ORDER BY n LIMIT 2
  356. }
  357. } {n 6 log 3 n 7 log 3}
  358. do_test select4-7.4 {
  359. execsql2 {
  360. SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2)
  361. ORDER BY n LIMIT 2
  362. }
  363. } {n 1 log 0 n 2 log 1}
  364. finish_test