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.30 2009/04/16 00:24:24 drh Exp $ 16 17set testdir [file dirname $argv0] 18source $testdir/tester.tcl 19 20# Most tests in this file depend on compound-select. But there are a couple 21# right at the end that test DISTINCT, so we cannot omit the entire file. 22# 23ifcapable compound { 24 25# Build some test data 26# 27execsql { 28 CREATE TABLE t1(n int, log int); 29 BEGIN; 30} 31for {set i 1} {$i<32} {incr i} { 32 for {set j 0} {(1<<$j)<$i} {incr j} {} 33 execsql "INSERT INTO t1 VALUES($i,$j)" 34} 35execsql { 36 COMMIT; 37} 38 39do_test select4-1.0 { 40 execsql {SELECT DISTINCT log FROM t1 ORDER BY log} 41} {0 1 2 3 4 5} 42 43# Union All operator 44# 45do_test select4-1.1a { 46 lsort [execsql {SELECT DISTINCT log FROM t1}] 47} {0 1 2 3 4 5} 48do_test select4-1.1b { 49 lsort [execsql {SELECT n FROM t1 WHERE log=3}] 50} {5 6 7 8} 51do_test select4-1.1c { 52 execsql { 53 SELECT DISTINCT log FROM t1 54 UNION ALL 55 SELECT n FROM t1 WHERE log=3 56 ORDER BY log; 57 } 58} {0 1 2 3 4 5 5 6 7 8} 59do_test select4-1.1d { 60 execsql { 61 CREATE TABLE t2 AS 62 SELECT DISTINCT log FROM t1 63 UNION ALL 64 SELECT n FROM t1 WHERE log=3 65 ORDER BY log; 66 SELECT * FROM t2; 67 } 68} {0 1 2 3 4 5 5 6 7 8} 69execsql {DROP TABLE t2} 70do_test select4-1.1e { 71 execsql { 72 CREATE TABLE t2 AS 73 SELECT DISTINCT log FROM t1 74 UNION ALL 75 SELECT n FROM t1 WHERE log=3 76 ORDER BY log DESC; 77 SELECT * FROM t2; 78 } 79} {8 7 6 5 5 4 3 2 1 0} 80execsql {DROP TABLE t2} 81do_test select4-1.1f { 82 execsql { 83 SELECT DISTINCT log FROM t1 84 UNION ALL 85 SELECT n FROM t1 WHERE log=2 86 } 87} {0 1 2 3 4 5 3 4} 88do_test select4-1.1g { 89 execsql { 90 CREATE TABLE t2 AS 91 SELECT DISTINCT log FROM t1 92 UNION ALL 93 SELECT n FROM t1 WHERE log=2; 94 SELECT * FROM t2; 95 } 96} {0 1 2 3 4 5 3 4} 97execsql {DROP TABLE t2} 98ifcapable subquery { 99 do_test select4-1.2 { 100 execsql { 101 SELECT log FROM t1 WHERE n IN 102 (SELECT DISTINCT log FROM t1 UNION ALL 103 SELECT n FROM t1 WHERE log=3) 104 ORDER BY log; 105 } 106 } {0 1 2 2 3 3 3 3} 107} 108 109# EVIDENCE-OF: R-02644-22131 In a compound SELECT statement, only the 110# last or right-most simple SELECT may have an ORDER BY clause. 111# 112do_test select4-1.3 { 113 set v [catch {execsql { 114 SELECT DISTINCT log FROM t1 ORDER BY log 115 UNION ALL 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 UNION ALL not before}} 121do_catchsql_test select4-1.4 { 122 SELECT (VALUES(0) INTERSECT SELECT(0) UNION SELECT(0) ORDER BY 1 UNION 123 SELECT 0 UNION SELECT 0 ORDER BY 1); 124} {1 {ORDER BY clause should come after UNION not before}} 125 126# Union operator 127# 128do_test select4-2.1 { 129 execsql { 130 SELECT DISTINCT log FROM t1 131 UNION 132 SELECT n FROM t1 WHERE log=3 133 ORDER BY log; 134 } 135} {0 1 2 3 4 5 6 7 8} 136ifcapable subquery { 137 do_test select4-2.2 { 138 execsql { 139 SELECT log FROM t1 WHERE n IN 140 (SELECT DISTINCT log FROM t1 UNION 141 SELECT n FROM t1 WHERE log=3) 142 ORDER BY log; 143 } 144 } {0 1 2 2 3 3 3 3} 145} 146do_test select4-2.3 { 147 set v [catch {execsql { 148 SELECT DISTINCT log FROM t1 ORDER BY log 149 UNION 150 SELECT n FROM t1 WHERE log=3 151 ORDER BY log; 152 }} msg] 153 lappend v $msg 154} {1 {ORDER BY clause should come after UNION not before}} 155do_test select4-2.4 { 156 set v [catch {execsql { 157 SELECT 0 ORDER BY (SELECT 0) UNION SELECT 0; 158 }} msg] 159 lappend v $msg 160} {1 {ORDER BY clause should come after UNION not before}} 161do_execsql_test select4-2.5 { 162 SELECT 123 AS x ORDER BY (SELECT x ORDER BY 1); 163} {123} 164 165# Except operator 166# 167do_test select4-3.1.1 { 168 execsql { 169 SELECT DISTINCT log FROM t1 170 EXCEPT 171 SELECT n FROM t1 WHERE log=3 172 ORDER BY log; 173 } 174} {0 1 2 3 4} 175do_test select4-3.1.2 { 176 execsql { 177 CREATE TABLE t2 AS 178 SELECT DISTINCT log FROM t1 179 EXCEPT 180 SELECT n FROM t1 WHERE log=3 181 ORDER BY log; 182 SELECT * FROM t2; 183 } 184} {0 1 2 3 4} 185execsql {DROP TABLE t2} 186do_test select4-3.1.3 { 187 execsql { 188 CREATE TABLE t2 AS 189 SELECT DISTINCT log FROM t1 190 EXCEPT 191 SELECT n FROM t1 WHERE log=3 192 ORDER BY log DESC; 193 SELECT * FROM t2; 194 } 195} {4 3 2 1 0} 196execsql {DROP TABLE t2} 197ifcapable subquery { 198 do_test select4-3.2 { 199 execsql { 200 SELECT log FROM t1 WHERE n IN 201 (SELECT DISTINCT log FROM t1 EXCEPT 202 SELECT n FROM t1 WHERE log=3) 203 ORDER BY log; 204 } 205 } {0 1 2 2} 206} 207do_test select4-3.3 { 208 set v [catch {execsql { 209 SELECT DISTINCT log FROM t1 ORDER BY log 210 EXCEPT 211 SELECT n FROM t1 WHERE log=3 212 ORDER BY log; 213 }} msg] 214 lappend v $msg 215} {1 {ORDER BY clause should come after EXCEPT not before}} 216 217# Intersect operator 218# 219do_test select4-4.1.1 { 220 execsql { 221 SELECT DISTINCT log FROM t1 222 INTERSECT 223 SELECT n FROM t1 WHERE log=3 224 ORDER BY log; 225 } 226} {5} 227 228do_test select4-4.1.2 { 229 execsql { 230 SELECT DISTINCT log FROM t1 231 UNION ALL 232 SELECT 6 233 INTERSECT 234 SELECT n FROM t1 WHERE log=3 235 ORDER BY t1.log; 236 } 237} {5 6} 238 239do_test select4-4.1.3 { 240 execsql { 241 CREATE TABLE t2 AS 242 SELECT DISTINCT log FROM t1 UNION ALL SELECT 6 243 INTERSECT 244 SELECT n FROM t1 WHERE log=3 245 ORDER BY log; 246 SELECT * FROM t2; 247 } 248} {5 6} 249execsql {DROP TABLE t2} 250do_test select4-4.1.4 { 251 execsql { 252 CREATE TABLE t2 AS 253 SELECT DISTINCT log FROM t1 UNION ALL SELECT 6 254 INTERSECT 255 SELECT n FROM t1 WHERE log=3 256 ORDER BY log DESC; 257 SELECT * FROM t2; 258 } 259} {6 5} 260execsql {DROP TABLE t2} 261ifcapable subquery { 262 do_test select4-4.2 { 263 execsql { 264 SELECT log FROM t1 WHERE n IN 265 (SELECT DISTINCT log FROM t1 INTERSECT 266 SELECT n FROM t1 WHERE log=3) 267 ORDER BY log; 268 } 269 } {3} 270} 271do_test select4-4.3 { 272 set v [catch {execsql { 273 SELECT DISTINCT log FROM t1 ORDER BY log 274 INTERSECT 275 SELECT n FROM t1 WHERE log=3 276 ORDER BY log; 277 }} msg] 278 lappend v $msg 279} {1 {ORDER BY clause should come after INTERSECT not before}} 280do_catchsql_test select4-4.4 { 281 SELECT 3 IN ( 282 SELECT 0 ORDER BY 1 283 INTERSECT 284 SELECT 1 285 INTERSECT 286 SELECT 2 287 ORDER BY 1 288 ); 289} {1 {ORDER BY clause should come after INTERSECT not before}} 290 291# Various error messages while processing UNION or INTERSECT 292# 293do_test select4-5.1 { 294 set v [catch {execsql { 295 SELECT DISTINCT log FROM t2 296 UNION ALL 297 SELECT n FROM t1 WHERE log=3 298 ORDER BY log; 299 }} msg] 300 lappend v $msg 301} {1 {no such table: t2}} 302do_test select4-5.2 { 303 set v [catch {execsql { 304 SELECT DISTINCT log AS "xyzzy" FROM t1 305 UNION ALL 306 SELECT n FROM t1 WHERE log=3 307 ORDER BY xyzzy; 308 }} msg] 309 lappend v $msg 310} {0 {0 1 2 3 4 5 5 6 7 8}} 311do_test select4-5.2b { 312 set v [catch {execsql { 313 SELECT DISTINCT log AS xyzzy FROM t1 314 UNION ALL 315 SELECT n FROM t1 WHERE log=3 316 ORDER BY "xyzzy"; 317 }} msg] 318 lappend v $msg 319} {0 {0 1 2 3 4 5 5 6 7 8}} 320do_test select4-5.2c { 321 set v [catch {execsql { 322 SELECT DISTINCT log FROM t1 323 UNION ALL 324 SELECT n FROM t1 WHERE log=3 325 ORDER BY "xyzzy"; 326 }} msg] 327 lappend v $msg 328} {1 {1st ORDER BY term does not match any column in the result set}} 329do_test select4-5.2d { 330 set v [catch {execsql { 331 SELECT DISTINCT log FROM t1 332 INTERSECT 333 SELECT n FROM t1 WHERE log=3 334 ORDER BY "xyzzy"; 335 }} msg] 336 lappend v $msg 337} {1 {1st ORDER BY term does not match any column in the result set}} 338do_test select4-5.2e { 339 set v [catch {execsql { 340 SELECT DISTINCT log FROM t1 341 UNION ALL 342 SELECT n FROM t1 WHERE log=3 343 ORDER BY n; 344 }} msg] 345 lappend v $msg 346} {0 {0 1 2 3 4 5 5 6 7 8}} 347do_test select4-5.2f { 348 catchsql { 349 SELECT DISTINCT log FROM t1 350 UNION ALL 351 SELECT n FROM t1 WHERE log=3 352 ORDER BY log; 353 } 354} {0 {0 1 2 3 4 5 5 6 7 8}} 355do_test select4-5.2g { 356 catchsql { 357 SELECT DISTINCT log FROM t1 358 UNION ALL 359 SELECT n FROM t1 WHERE log=3 360 ORDER BY 1; 361 } 362} {0 {0 1 2 3 4 5 5 6 7 8}} 363do_test select4-5.2h { 364 catchsql { 365 SELECT DISTINCT log FROM t1 366 UNION ALL 367 SELECT n FROM t1 WHERE log=3 368 ORDER BY 2; 369 } 370} {1 {1st ORDER BY term out of range - should be between 1 and 1}} 371do_test select4-5.2i { 372 catchsql { 373 SELECT DISTINCT 1, log FROM t1 374 UNION ALL 375 SELECT 2, n FROM t1 WHERE log=3 376 ORDER BY 2, 1; 377 } 378} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}} 379do_test select4-5.2j { 380 catchsql { 381 SELECT DISTINCT 1, log FROM t1 382 UNION ALL 383 SELECT 2, n FROM t1 WHERE log=3 384 ORDER BY 1, 2 DESC; 385 } 386} {0 {1 5 1 4 1 3 1 2 1 1 1 0 2 8 2 7 2 6 2 5}} 387do_test select4-5.2k { 388 catchsql { 389 SELECT DISTINCT 1, log FROM t1 390 UNION ALL 391 SELECT 2, n FROM t1 WHERE log=3 392 ORDER BY n, 1; 393 } 394} {0 {1 0 1 1 1 2 1 3 1 4 1 5 2 5 2 6 2 7 2 8}} 395do_test select4-5.3 { 396 set v [catch {execsql { 397 SELECT DISTINCT log, n FROM t1 398 UNION ALL 399 SELECT n FROM t1 WHERE log=3 400 ORDER BY log; 401 }} msg] 402 lappend v $msg 403} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}} 404do_test select4-5.3-3807-1 { 405 catchsql { 406 SELECT 1 UNION SELECT 2, 3 UNION SELECT 4, 5 ORDER BY 1; 407 } 408} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 409do_test select4-5.4 { 410 set v [catch {execsql { 411 SELECT log FROM t1 WHERE n=2 412 UNION ALL 413 SELECT log FROM t1 WHERE n=3 414 UNION ALL 415 SELECT log FROM t1 WHERE n=4 416 UNION ALL 417 SELECT log FROM t1 WHERE n=5 418 ORDER BY log; 419 }} msg] 420 lappend v $msg 421} {0 {1 2 2 3}} 422 423do_test select4-6.1 { 424 execsql { 425 SELECT log, count(*) as cnt FROM t1 GROUP BY log 426 UNION 427 SELECT log, n FROM t1 WHERE n=7 428 ORDER BY cnt, log; 429 } 430} {0 1 1 1 2 2 3 4 3 7 4 8 5 15} 431do_test select4-6.2 { 432 execsql { 433 SELECT log, count(*) FROM t1 GROUP BY log 434 UNION 435 SELECT log, n FROM t1 WHERE n=7 436 ORDER BY count(*), log; 437 } 438} {0 1 1 1 2 2 3 4 3 7 4 8 5 15} 439 440# NULLs are indistinct for the UNION operator. 441# Make sure the UNION operator recognizes this 442# 443do_test select4-6.3 { 444 execsql { 445 SELECT NULL UNION SELECT NULL UNION 446 SELECT 1 UNION SELECT 2 AS 'x' 447 ORDER BY x; 448 } 449} {{} 1 2} 450do_test select4-6.3.1 { 451 execsql { 452 SELECT NULL UNION ALL SELECT NULL UNION ALL 453 SELECT 1 UNION ALL SELECT 2 AS 'x' 454 ORDER BY x; 455 } 456} {{} {} 1 2} 457 458# Make sure the DISTINCT keyword treats NULLs as indistinct. 459# 460ifcapable subquery { 461 do_test select4-6.4 { 462 execsql { 463 SELECT * FROM ( 464 SELECT NULL, 1 UNION ALL SELECT NULL, 1 465 ); 466 } 467 } {{} 1 {} 1} 468 do_test select4-6.5 { 469 execsql { 470 SELECT DISTINCT * FROM ( 471 SELECT NULL, 1 UNION ALL SELECT NULL, 1 472 ); 473 } 474 } {{} 1} 475 do_test select4-6.6 { 476 execsql { 477 SELECT DISTINCT * FROM ( 478 SELECT 1,2 UNION ALL SELECT 1,2 479 ); 480 } 481 } {1 2} 482} 483 484# Test distinctness of NULL in other ways. 485# 486do_test select4-6.7 { 487 execsql { 488 SELECT NULL EXCEPT SELECT NULL 489 } 490} {} 491 492 493# Make sure column names are correct when a compound select appears as 494# an expression in the WHERE clause. 495# 496do_test select4-7.1 { 497 execsql { 498 CREATE TABLE t2 AS SELECT log AS 'x', count(*) AS 'y' FROM t1 GROUP BY log; 499 SELECT * FROM t2 ORDER BY x; 500 } 501} {0 1 1 1 2 2 3 4 4 8 5 15} 502ifcapable subquery { 503 do_test select4-7.2 { 504 execsql2 { 505 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 INTERSECT SELECT x FROM t2) 506 ORDER BY n 507 } 508 } {n 1 log 0 n 2 log 1 n 3 log 2 n 4 log 2 n 5 log 3} 509 do_test select4-7.3 { 510 execsql2 { 511 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 EXCEPT SELECT x FROM t2) 512 ORDER BY n LIMIT 2 513 } 514 } {n 6 log 3 n 7 log 3} 515 do_test select4-7.4 { 516 execsql2 { 517 SELECT * FROM t1 WHERE n IN (SELECT n FROM t1 UNION SELECT x FROM t2) 518 ORDER BY n LIMIT 2 519 } 520 } {n 1 log 0 n 2 log 1} 521} ;# ifcapable subquery 522 523} ;# ifcapable compound 524 525# Make sure DISTINCT works appropriately on TEXT and NUMERIC columns. 526do_test select4-8.1 { 527 execsql { 528 BEGIN; 529 CREATE TABLE t3(a text, b float, c text); 530 INSERT INTO t3 VALUES(1, 1.1, '1.1'); 531 INSERT INTO t3 VALUES(2, 1.10, '1.10'); 532 INSERT INTO t3 VALUES(3, 1.10, '1.1'); 533 INSERT INTO t3 VALUES(4, 1.1, '1.10'); 534 INSERT INTO t3 VALUES(5, 1.2, '1.2'); 535 INSERT INTO t3 VALUES(6, 1.3, '1.3'); 536 COMMIT; 537 } 538 execsql { 539 SELECT DISTINCT b FROM t3 ORDER BY c; 540 } 541} {1.1 1.2 1.3} 542do_test select4-8.2 { 543 execsql { 544 SELECT DISTINCT c FROM t3 ORDER BY c; 545 } 546} {1.1 1.10 1.2 1.3} 547 548# Make sure the names of columns are taken from the right-most subquery 549# right in a compound query. Ticket #1721 550# 551ifcapable compound { 552 553do_test select4-9.1 { 554 execsql2 { 555 SELECT x, y FROM t2 UNION SELECT a, b FROM t3 ORDER BY x LIMIT 1 556 } 557} {x 0 y 1} 558do_test select4-9.2 { 559 execsql2 { 560 SELECT x, y FROM t2 UNION ALL SELECT a, b FROM t3 ORDER BY x LIMIT 1 561 } 562} {x 0 y 1} 563do_test select4-9.3 { 564 execsql2 { 565 SELECT x, y FROM t2 EXCEPT SELECT a, b FROM t3 ORDER BY x LIMIT 1 566 } 567} {x 0 y 1} 568do_test select4-9.4 { 569 execsql2 { 570 SELECT x, y FROM t2 INTERSECT SELECT 0 AS a, 1 AS b; 571 } 572} {x 0 y 1} 573do_test select4-9.5 { 574 execsql2 { 575 SELECT 0 AS x, 1 AS y 576 UNION 577 SELECT 2 AS p, 3 AS q 578 UNION 579 SELECT 4 AS a, 5 AS b 580 ORDER BY x LIMIT 1 581 } 582} {x 0 y 1} 583 584ifcapable subquery { 585do_test select4-9.6 { 586 execsql2 { 587 SELECT * FROM ( 588 SELECT 0 AS x, 1 AS y 589 UNION 590 SELECT 2 AS p, 3 AS q 591 UNION 592 SELECT 4 AS a, 5 AS b 593 ) ORDER BY 1 LIMIT 1; 594 } 595} {x 0 y 1} 596do_test select4-9.7 { 597 execsql2 { 598 SELECT * FROM ( 599 SELECT 0 AS x, 1 AS y 600 UNION 601 SELECT 2 AS p, 3 AS q 602 UNION 603 SELECT 4 AS a, 5 AS b 604 ) ORDER BY x LIMIT 1; 605 } 606} {x 0 y 1} 607} ;# ifcapable subquery 608 609do_test select4-9.8 { 610 execsql { 611 SELECT 0 AS x, 1 AS y 612 UNION 613 SELECT 2 AS y, -3 AS x 614 ORDER BY x LIMIT 1; 615 } 616} {0 1} 617 618do_test select4-9.9.1 { 619 execsql2 { 620 SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a 621 } 622} {a 1 b 2 a 3 b 4} 623 624ifcapable subquery { 625do_test select4-9.9.2 { 626 execsql2 { 627 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a) 628 WHERE b=3 629 } 630} {} 631do_test select4-9.10 { 632 execsql2 { 633 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS b, 4 AS a) 634 WHERE b=2 635 } 636} {a 1 b 2} 637do_test select4-9.11 { 638 execsql2 { 639 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b) 640 WHERE b=2 641 } 642} {a 1 b 2} 643do_test select4-9.12 { 644 execsql2 { 645 SELECT * FROM (SELECT 1 AS a, 2 AS b UNION ALL SELECT 3 AS e, 4 AS b) 646 WHERE b>0 647 } 648} {a 1 b 2 a 3 b 4} 649} ;# ifcapable subquery 650 651# Try combining DISTINCT, LIMIT, and OFFSET. Make sure they all work 652# together. 653# 654do_test select4-10.1 { 655 execsql { 656 SELECT DISTINCT log FROM t1 ORDER BY log 657 } 658} {0 1 2 3 4 5} 659do_test select4-10.2 { 660 execsql { 661 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 4 662 } 663} {0 1 2 3} 664do_test select4-10.3 { 665 execsql { 666 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0 667 } 668} {} 669do_test select4-10.4 { 670 execsql { 671 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1 672 } 673} {0 1 2 3 4 5} 674do_test select4-10.5 { 675 execsql { 676 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT -1 OFFSET 2 677 } 678} {2 3 4 5} 679do_test select4-10.6 { 680 execsql { 681 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 3 OFFSET 2 682 } 683} {2 3 4} 684do_test select4-10.7 { 685 execsql { 686 SELECT DISTINCT log FROM t1 ORDER BY +log LIMIT 3 OFFSET 20 687 } 688} {} 689do_test select4-10.8 { 690 execsql { 691 SELECT DISTINCT log FROM t1 ORDER BY log LIMIT 0 OFFSET 3 692 } 693} {} 694do_test select4-10.9 { 695 execsql { 696 SELECT DISTINCT max(n), log FROM t1 ORDER BY +log; -- LIMIT 2 OFFSET 1 697 } 698} {31 5} 699 700# Make sure compound SELECTs with wildly different numbers of columns 701# do not cause assertion faults due to register allocation issues. 702# 703do_test select4-11.1 { 704 catchsql { 705 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 706 UNION 707 SELECT x FROM t2 708 } 709} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 710do_test select4-11.2 { 711 catchsql { 712 SELECT x FROM t2 713 UNION 714 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 715 } 716} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 717do_test select4-11.3 { 718 catchsql { 719 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 720 UNION ALL 721 SELECT x FROM t2 722 } 723} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}} 724do_test select4-11.4 { 725 catchsql { 726 SELECT x FROM t2 727 UNION ALL 728 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 729 } 730} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}} 731do_test select4-11.5 { 732 catchsql { 733 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 734 EXCEPT 735 SELECT x FROM t2 736 } 737} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}} 738do_test select4-11.6 { 739 catchsql { 740 SELECT x FROM t2 741 EXCEPT 742 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 743 } 744} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}} 745do_test select4-11.7 { 746 catchsql { 747 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 748 INTERSECT 749 SELECT x FROM t2 750 } 751} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}} 752do_test select4-11.8 { 753 catchsql { 754 SELECT x FROM t2 755 INTERSECT 756 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 757 } 758} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}} 759 760do_test select4-11.11 { 761 catchsql { 762 SELECT x FROM t2 763 UNION 764 SELECT x FROM t2 765 UNION ALL 766 SELECT x FROM t2 767 EXCEPT 768 SELECT x FROM t2 769 INTERSECT 770 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 771 } 772} {1 {SELECTs to the left and right of INTERSECT do not have the same number of result columns}} 773do_test select4-11.12 { 774 catchsql { 775 SELECT x FROM t2 776 UNION 777 SELECT x FROM t2 778 UNION ALL 779 SELECT x FROM t2 780 EXCEPT 781 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 782 EXCEPT 783 SELECT x FROM t2 784 } 785} {1 {SELECTs to the left and right of EXCEPT do not have the same number of result columns}} 786do_test select4-11.13 { 787 catchsql { 788 SELECT x FROM t2 789 UNION 790 SELECT x FROM t2 791 UNION ALL 792 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 793 UNION ALL 794 SELECT x FROM t2 795 EXCEPT 796 SELECT x FROM t2 797 } 798} {1 {SELECTs to the left and right of UNION ALL do not have the same number of result columns}} 799do_test select4-11.14 { 800 catchsql { 801 SELECT x FROM t2 802 UNION 803 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 804 UNION 805 SELECT x FROM t2 806 UNION ALL 807 SELECT x FROM t2 808 EXCEPT 809 SELECT x FROM t2 810 } 811} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 812do_test select4-11.15 { 813 catchsql { 814 SELECT x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x,x FROM t2 815 UNION 816 SELECT x FROM t2 817 INTERSECT 818 SELECT x FROM t2 819 UNION ALL 820 SELECT x FROM t2 821 EXCEPT 822 SELECT x FROM t2 823 } 824} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 825do_test select4-11.16 { 826 catchsql { 827 INSERT INTO t2(rowid) VALUES(2) UNION SELECT 3,4 UNION SELECT 5,6 ORDER BY 1; 828 } 829} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 830 831do_test select4-12.1 { 832 sqlite3 db2 :memory: 833 catchsql { 834 SELECT 1 UNION SELECT 2,3 UNION SELECT 4,5 ORDER BY 1; 835 } db2 836} {1 {SELECTs to the left and right of UNION do not have the same number of result columns}} 837 838} ;# ifcapable compound 839 840 841# Ticket [3557ad65a076c] - Incorrect DISTINCT processing with an 842# indexed query using IN. 843# 844do_test select4-13.1 { 845 sqlite3 db test.db 846 db eval { 847 CREATE TABLE t13(a,b); 848 INSERT INTO t13 VALUES(1,1); 849 INSERT INTO t13 VALUES(2,1); 850 INSERT INTO t13 VALUES(3,1); 851 INSERT INTO t13 VALUES(2,2); 852 INSERT INTO t13 VALUES(3,2); 853 INSERT INTO t13 VALUES(4,2); 854 CREATE INDEX t13ab ON t13(a,b); 855 SELECT DISTINCT b from t13 WHERE a IN (1,2,3); 856 } 857} {1 2} 858 859# 2014-02-18: Make sure compound SELECTs work with VALUES clauses 860# 861do_execsql_test select4-14.1 { 862 CREATE TABLE t14(a,b,c); 863 INSERT INTO t14 VALUES(1,2,3),(4,5,6); 864 SELECT * FROM t14 INTERSECT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3); 865} {1 2 3} 866do_execsql_test select4-14.2 { 867 SELECT * FROM t14 INTERSECT VALUES(1,2,3); 868} {1 2 3} 869do_execsql_test select4-14.3 { 870 SELECT * FROM t14 871 UNION VALUES(3,2,1),(2,3,1),(1,2,3),(7,8,9),(4,5,6) 872 UNION SELECT * FROM t14 ORDER BY 1, 2, 3 873} {1 2 3 2 3 1 3 2 1 4 5 6 7 8 9} 874do_execsql_test select4-14.4 { 875 SELECT * FROM t14 876 UNION VALUES(3,2,1) 877 UNION SELECT * FROM t14 ORDER BY 1, 2, 3 878} {1 2 3 3 2 1 4 5 6} 879do_execsql_test select4-14.5 { 880 SELECT * FROM t14 EXCEPT VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3); 881} {4 5 6} 882do_execsql_test select4-14.6 { 883 SELECT * FROM t14 EXCEPT VALUES(1,2,3) 884} {4 5 6} 885do_execsql_test select4-14.7 { 886 SELECT * FROM t14 EXCEPT VALUES(1,2,3) EXCEPT VALUES(4,5,6) 887} {} 888do_execsql_test select4-14.8 { 889 SELECT * FROM t14 EXCEPT VALUES('a','b','c') EXCEPT VALUES(4,5,6) 890} {1 2 3} 891do_execsql_test select4-14.9 { 892 SELECT * FROM t14 UNION ALL VALUES(3,2,1),(2,3,1),(1,2,3),(2,1,3); 893} {1 2 3 4 5 6 3 2 1 2 3 1 1 2 3 2 1 3} 894do_execsql_test select4-14.10 { 895 SELECT (VALUES(1),(2),(3),(4)) 896} {1} 897do_execsql_test select4-14.11 { 898 SELECT (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL SELECT 4) 899} {1} 900do_execsql_test select4-14.12 { 901 VALUES(1) UNION VALUES(2); 902} {1 2} 903do_execsql_test select4-14.13 { 904 VALUES(1),(2),(3) EXCEPT VALUES(2); 905} {1 3} 906do_execsql_test select4-14.14 { 907 VALUES(1),(2),(3) EXCEPT VALUES(1),(3); 908} {2} 909do_execsql_test select4-14.15 { 910 SELECT * FROM (SELECT 123), (SELECT 456) ON likely(0 OR 1) OR 0; 911} {123 456} 912do_execsql_test select4-14.16 { 913 VALUES(1),(2),(3),(4) UNION ALL SELECT 5 LIMIT 99; 914} {1 2 3 4 5} 915do_execsql_test select4-14.17 { 916 VALUES(1),(2),(3),(4) UNION ALL SELECT 5 LIMIT 3; 917} {1 2 3} 918 919finish_test 920