1# 2# 2002 May 24 3# 4# The author disclaims copyright to this source code. In place of 5# a legal notice, here is a blessing: 6# 7# May you do good and not evil. 8# May you find forgiveness for yourself and forgive others. 9# May you share freely, never taking more than you give. 10# 11#*********************************************************************** 12# This file implements regression tests for SQLite library. 13# 14# This file implements tests for joins, including outer joins. 15# 16# $Id: join.test,v 1.11 2003/09/27 13:39:40 drh Exp $ 17 18set testdir [file dirname $argv0] 19source $testdir/tester.tcl 20 21do_test join-1.1 { 22 execsql { 23 CREATE TABLE t1(a,b,c); 24 INSERT INTO t1 VALUES(1,2,3); 25 INSERT INTO t1 VALUES(2,3,4); 26 INSERT INTO t1 VALUES(3,4,5); 27 SELECT * FROM t1; 28 } 29} {1 2 3 2 3 4 3 4 5} 30do_test join-1.2 { 31 execsql { 32 CREATE TABLE t2(b,c,d); 33 INSERT INTO t2 VALUES(1,2,3); 34 INSERT INTO t2 VALUES(2,3,4); 35 INSERT INTO t2 VALUES(3,4,5); 36 SELECT * FROM t2; 37 } 38} {1 2 3 2 3 4 3 4 5} 39 40do_test join-1.3 { 41 execsql2 { 42 SELECT * FROM t1 NATURAL JOIN t2; 43 } 44} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5} 45do_test join-1.3.1 { 46 execsql2 { 47 SELECT * FROM t2 NATURAL JOIN t1; 48 } 49} {t2.b 2 t2.c 3 t2.d 4 t1.a 1 t2.b 3 t2.c 4 t2.d 5 t1.a 2} 50do_test join-1.4 { 51 execsql2 { 52 SELECT * FROM t1 INNER JOIN t2 USING(b,c); 53 } 54} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5} 55do_test join-1.5 { 56 execsql2 { 57 SELECT * FROM t1 INNER JOIN t2 USING(b); 58 } 59} {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} 60do_test join-1.6 { 61 execsql2 { 62 SELECT * FROM t1 INNER JOIN t2 USING(c); 63 } 64} {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} 65do_test join-1.7 { 66 execsql2 { 67 SELECT * FROM t1 INNER JOIN t2 USING(c,b); 68 } 69} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t1.a 2 t1.b 3 t1.c 4 t2.d 5} 70 71do_test join-1.8 { 72 execsql { 73 SELECT * FROM t1 NATURAL CROSS JOIN t2; 74 } 75} {1 2 3 4 2 3 4 5} 76do_test join-1.9 { 77 execsql { 78 SELECT * FROM t1 CROSS JOIN t2 USING(b,c); 79 } 80} {1 2 3 4 2 3 4 5} 81do_test join-1.10 { 82 execsql { 83 SELECT * FROM t1 NATURAL INNER JOIN t2; 84 } 85} {1 2 3 4 2 3 4 5} 86do_test join-1.11 { 87 execsql { 88 SELECT * FROM t1 INNER JOIN t2 USING(b,c); 89 } 90} {1 2 3 4 2 3 4 5} 91do_test join-1.12 { 92 execsql { 93 SELECT * FROM t1 natural inner join t2; 94 } 95} {1 2 3 4 2 3 4 5} 96do_test join-1.13 { 97 execsql2 { 98 SELECT * FROM t1 NATURAL JOIN 99 (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as t3 100 } 101} {t1.a 1 t1.b 2 t1.c 3 t3.d 4 t3.e 5} 102do_test join-1.14 { 103 execsql2 { 104 SELECT * FROM (SELECT b as 'c', c as 'd', d as 'e' FROM t2) as 'tx' 105 NATURAL JOIN t1 106 } 107} {tx.c 3 tx.d 4 tx.e 5 t1.a 1 t1.b 2} 108 109do_test join-1.15 { 110 execsql { 111 CREATE TABLE t3(c,d,e); 112 INSERT INTO t3 VALUES(2,3,4); 113 INSERT INTO t3 VALUES(3,4,5); 114 INSERT INTO t3 VALUES(4,5,6); 115 SELECT * FROM t3; 116 } 117} {2 3 4 3 4 5 4 5 6} 118do_test join-1.16 { 119 execsql { 120 SELECT * FROM t1 natural join t2 natural join t3; 121 } 122} {1 2 3 4 5 2 3 4 5 6} 123do_test join-1.17 { 124 execsql2 { 125 SELECT * FROM t1 natural join t2 natural join t3; 126 } 127} {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} 128do_test join-1.18 { 129 execsql { 130 CREATE TABLE t4(d,e,f); 131 INSERT INTO t4 VALUES(2,3,4); 132 INSERT INTO t4 VALUES(3,4,5); 133 INSERT INTO t4 VALUES(4,5,6); 134 SELECT * FROM t4; 135 } 136} {2 3 4 3 4 5 4 5 6} 137do_test join-1.19 { 138 execsql { 139 SELECT * FROM t1 natural join t2 natural join t4; 140 } 141} {1 2 3 4 5 6} 142do_test join-1.19 { 143 execsql2 { 144 SELECT * FROM t1 natural join t2 natural join t4; 145 } 146} {t1.a 1 t1.b 2 t1.c 3 t2.d 4 t4.e 5 t4.f 6} 147do_test join-1.20 { 148 execsql { 149 SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1 150 } 151} {1 2 3 4 5} 152 153do_test join-2.1 { 154 execsql { 155 SELECT * FROM t1 NATURAL LEFT JOIN t2; 156 } 157} {1 2 3 4 2 3 4 5 3 4 5 {}} 158do_test join-2.2 { 159 execsql { 160 SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1; 161 } 162} {1 2 3 {} 2 3 4 1 3 4 5 2} 163do_test join-2.3 { 164 catchsql { 165 SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2; 166 } 167} {1 {RIGHT and FULL OUTER JOINs are not currently supported}} 168do_test join-2.4 { 169 execsql { 170 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d 171 } 172} {1 2 3 {} {} {} 2 3 4 {} {} {} 3 4 5 1 2 3} 173do_test join-2.5 { 174 execsql { 175 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1 176 } 177} {2 3 4 {} {} {} 3 4 5 1 2 3} 178do_test join-2.6 { 179 execsql { 180 SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1 181 } 182} {1 2 3 {} {} {} 2 3 4 {} {} {}} 183 184do_test join-3.1 { 185 catchsql { 186 SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b; 187 } 188} {1 {a NATURAL join may not have an ON or USING clause}} 189do_test join-3.2 { 190 catchsql { 191 SELECT * FROM t1 NATURAL JOIN t2 USING(b); 192 } 193} {1 {a NATURAL join may not have an ON or USING clause}} 194do_test join-3.3 { 195 catchsql { 196 SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b); 197 } 198} {1 {cannot have both ON and USING clauses in the same join}} 199do_test join-3.4 { 200 catchsql { 201 SELECT * FROM t1 JOIN t2 USING(a); 202 } 203} {1 {cannot join using column a - column not present in both tables}} 204do_test join-3.5 { 205 catchsql { 206 SELECT * FROM t1 USING(a); 207 } 208} {0 {1 2 3 2 3 4 3 4 5}} 209do_test join-3.6 { 210 catchsql { 211 SELECT * FROM t1 JOIN t2 ON t3.a=t2.b; 212 } 213} {1 {no such column: t3.a}} 214do_test join-3.7 { 215 catchsql { 216 SELECT * FROM t1 INNER OUTER JOIN t2; 217 } 218} {1 {unknown or unsupported join type: INNER OUTER}} 219do_test join-3.7 { 220 catchsql { 221 SELECT * FROM t1 LEFT BOGUS JOIN t2; 222 } 223} {1 {unknown or unsupported join type: LEFT BOGUS}} 224 225do_test join-4.1 { 226 execsql { 227 BEGIN; 228 CREATE TABLE t5(a INTEGER PRIMARY KEY); 229 CREATE TABLE t6(a INTEGER); 230 INSERT INTO t6 VALUES(NULL); 231 INSERT INTO t6 VALUES(NULL); 232 INSERT INTO t6 SELECT * FROM t6; 233 INSERT INTO t6 SELECT * FROM t6; 234 INSERT INTO t6 SELECT * FROM t6; 235 INSERT INTO t6 SELECT * FROM t6; 236 INSERT INTO t6 SELECT * FROM t6; 237 INSERT INTO t6 SELECT * FROM t6; 238 COMMIT; 239 } 240 execsql { 241 SELECT * FROM t6 NATURAL JOIN t5; 242 } 243} {} 244do_test join-4.2 { 245 execsql { 246 SELECT * FROM t6, t5 WHERE t6.a<t5.a; 247 } 248} {} 249do_test join-4.3 { 250 execsql { 251 SELECT * FROM t6, t5 WHERE t6.a>t5.a; 252 } 253} {} 254do_test join-4.4 { 255 execsql { 256 UPDATE t6 SET a='xyz'; 257 SELECT * FROM t6 NATURAL JOIN t5; 258 } 259} {} 260do_test join-4.6 { 261 execsql { 262 SELECT * FROM t6, t5 WHERE t6.a<t5.a; 263 } 264} {} 265do_test join-4.7 { 266 execsql { 267 SELECT * FROM t6, t5 WHERE t6.a>t5.a; 268 } 269} {} 270do_test join-4.8 { 271 execsql { 272 UPDATE t6 SET a=1; 273 SELECT * FROM t6 NATURAL JOIN t5; 274 } 275} {} 276do_test join-4.9 { 277 execsql { 278 SELECT * FROM t6, t5 WHERE t6.a<t5.a; 279 } 280} {} 281do_test join-4.10 { 282 execsql { 283 SELECT * FROM t6, t5 WHERE t6.a>t5.a; 284 } 285} {} 286 287do_test join-5.1 { 288 execsql { 289 BEGIN; 290 create table centros (id integer primary key, centro); 291 INSERT INTO centros VALUES(1,'xxx'); 292 create table usuarios (id integer primary key, nombre, apellidos, 293 idcentro integer); 294 INSERT INTO usuarios VALUES(1,'a','aa',1); 295 INSERT INTO usuarios VALUES(2,'b','bb',1); 296 INSERT INTO usuarios VALUES(3,'c','cc',NULL); 297 create index idcentro on usuarios (idcentro); 298 END; 299 select usuarios.id, usuarios.nombre, centros.centro from 300 usuarios left outer join centros on usuarios.idcentro = centros.id; 301 } 302} {1 a xxx 2 b xxx 3 c {}} 303 304# A test for ticket #247. 305# 306do_test join-7.1 { 307 execsql { 308 CREATE TABLE t7 (x, y); 309 INSERT INTO t7 VALUES ("pa1", 1); 310 INSERT INTO t7 VALUES ("pa2", NULL); 311 INSERT INTO t7 VALUES ("pa3", NULL); 312 INSERT INTO t7 VALUES ("pa4", 2); 313 INSERT INTO t7 VALUES ("pa30", 131); 314 INSERT INTO t7 VALUES ("pa31", 130); 315 INSERT INTO t7 VALUES ("pa28", NULL); 316 317 CREATE TABLE t8 (a integer primary key, b); 318 INSERT INTO t8 VALUES (1, "pa1"); 319 INSERT INTO t8 VALUES (2, "pa4"); 320 INSERT INTO t8 VALUES (3, NULL); 321 INSERT INTO t8 VALUES (4, NULL); 322 INSERT INTO t8 VALUES (130, "pa31"); 323 INSERT INTO t8 VALUES (131, "pa30"); 324 325 SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a; 326 } 327} {1 999 999 2 131 130 999} 328 329# Make sure a left join where the right table is really a view that 330# is itself a join works right. Ticket #306. 331# 332do_test join-8.1 { 333 execsql { 334 BEGIN; 335 CREATE TABLE t9(a INTEGER PRIMARY KEY, b); 336 INSERT INTO t9 VALUES(1,11); 337 INSERT INTO t9 VALUES(2,22); 338 CREATE TABLE t10(x INTEGER PRIMARY KEY, y); 339 INSERT INTO t10 VALUES(1,2); 340 INSERT INTO t10 VALUES(3,3); 341 CREATE TABLE t11(p INTEGER PRIMARY KEY, q); 342 INSERT INTO t11 VALUES(2,111); 343 INSERT INTO t11 VALUES(3,333); 344 CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p; 345 COMMIT; 346 SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x ); 347 } 348} {1 11 1 111 2 22 {} {}} 349do_test join-8.2 { 350 execsql { 351 SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p) 352 ON( a=x); 353 } 354} {1 11 1 111 2 22 {} {}} 355do_test join-8.3 { 356 execsql { 357 SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x ); 358 } 359} {1 111 1 11 3 333 {} {}} 360 361# Ticket #350 describes a scenario where LEFT OUTER JOIN does not 362# function correctly if the right table in the join is really 363# subquery. 364# 365# To test the problem, we generate the same LEFT OUTER JOIN in two 366# separate selects but with on using a subquery and the other calling 367# the table directly. Then connect the two SELECTs using an EXCEPT. 368# Both queries should generate the same results so the answer should 369# be an empty set. 370# 371do_test join-9.1 { 372 execsql { 373 BEGIN; 374 CREATE TABLE t12(a,b); 375 INSERT INTO t12 VALUES(1,11); 376 INSERT INTO t12 VALUES(2,22); 377 CREATE TABLE t13(b,c); 378 INSERT INTO t13 VALUES(22,222); 379 COMMIT; 380 SELECT * FROM t12 NATURAL LEFT JOIN t13 381 EXCEPT 382 SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0); 383 } 384} {} 385do_test join-9.2 { 386 execsql { 387 CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0; 388 SELECT * FROM t12 NATURAL LEFT JOIN t13 389 EXCEPT 390 SELECT * FROM t12 NATURAL LEFT JOIN v13; 391 } 392} {} 393 394finish_test 395