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