1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121
|
#!/usr/bin/env tarantool
test = require("sqltester")
NULL = require('msgpack').NULL
test:plan(92)
--!./tcltestrunner.lua
-- 2002 May 24
--
-- The author disclaims copyright to this source code. In place of
-- a legal notice, here is a blessing:
--
-- May you do good and not evil.
-- May you find forgiveness for yourself and forgive others.
-- May you share freely, never taking more than you give.
--
-------------------------------------------------------------------------
-- This file implements regression tests for sql library.
--
-- This file implements tests for joins, including outer joins.
--
-- $Id: join.test,v 1.27 2009/07/01 16:12:08 danielk1977 Exp $
-- ["set","testdir",[["file","dirname",["argv0"]]]]
-- ["source",[["testdir"],"\/tester.tcl"]]
test:do_execsql_test(
"join-1.1",
[[
CREATE TABLE t1(a INT primary key,b INT,c INT);
INSERT INTO t1 VALUES(1,2,3);
INSERT INTO t1 VALUES(2,3,4);
INSERT INTO t1 VALUES(3,4,5);
SELECT * FROM t1;
]], {
-- <join-1.1>
1, 2, 3, 2, 3, 4, 3, 4, 5
-- </join-1.1>
})
test:do_execsql_test(
"join-1.2",
[[
CREATE TABLE t2(b INT primary key,c INT,d INT);
INSERT INTO t2 VALUES(1,2,3);
INSERT INTO t2 VALUES(2,3,4);
INSERT INTO t2 VALUES(3,4,5);
SELECT * FROM t2;
]], {
-- <join-1.2>
1, 2, 3, 2, 3, 4, 3, 4, 5
-- </join-1.2>
})
-- # A FROM clause of the form: "<table>, <table> ON <expr>" is not
-- # allowed by the sql syntax diagram, nor by any other SQL database
-- # engine that we are aware of. Nevertheless, historic versions of
-- # sql have allowed it. We need to continue to support it moving
-- # forward to prevent breakage of legacy applications. Though, we will
-- # not advertise it as being supported.
-- #
-- do_execsql_test join-1.2.1 {
-- SELECT t1.rowid, t2.rowid, '|' FROM t1, t2 ON t1.a=t2.b;
-- } {1 1 | 2 2 | 3 3 |}
test:do_execsql2_test(
"join-1.3",
[[
SELECT * FROM t1 NATURAL JOIN t2;
]], {
-- <join-1.3>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.3>
})
test:do_execsql2_test(
"join-1.3.1",
[[
SELECT * FROM t2 NATURAL JOIN t1;
]], {
-- <join-1.3.1>
"B", 2, "C", 3, "D", 4, "A", 1, "B", 3, "C", 4, "D", 5, "A", 2
-- </join-1.3.1>
})
test:do_execsql2_test(
"join-1.3.2",
[[
SELECT * FROM t2 AS x NATURAL JOIN t1;
]], {
-- <join-1.3.2>
"B", 2, "C", 3, "D", 4, "A", 1, "B", 3, "C", 4, "D", 5, "A", 2
-- </join-1.3.2>
})
test:do_execsql2_test(
"join-1.3.3",
[[
SELECT * FROM t2 NATURAL JOIN t1 AS y;
]], {
-- <join-1.3.3>
"B", 2, "C", 3, "D", 4, "A", 1, "B", 3, "C", 4, "D", 5, "A", 2
-- </join-1.3.3>
})
test:do_execsql_test(
"join-1.3.4",
[[
SELECT b FROM t1 NATURAL JOIN t2;
]], {
-- <join-1.3.4>
2, 3
-- </join-1.3.4>
})
-- ticket #3522
test:do_execsql2_test(
"join-1.3.5",
[[
SELECT t2.* FROM t2 NATURAL JOIN t1
]], {
-- <join-1.3.5>
"B", 2, "C", 3, "D", 4, "B", 3, "C", 4, "D", 5
-- </join-1.3.5>
})
test:do_execsql2_test(
"join-1.3.6",
[[
SELECT xyzzy.* FROM t2 AS xyzzy NATURAL JOIN t1
]], {
-- <join-1.3.6>
"B", 2, "C", 3, "D", 4, "B", 3, "C", 4, "D", 5
-- </join-1.3.6>
})
test:do_execsql2_test(
"join-1.3.7",
[[
SELECT t1.* FROM t2 NATURAL JOIN t1
]], {
-- <join-1.3.7>
"A", 1, "B", 2, "C", 3, "A", 2, "B", 3, "C", 4
-- </join-1.3.7>
})
test:do_execsql2_test(
"join-1.3.8",
[[
SELECT xyzzy.* FROM t2 NATURAL JOIN t1 AS xyzzy
]], {
-- <join-1.3.8>
"A", 1, "B", 2, "C", 3, "A", 2, "B", 3, "C", 4
-- </join-1.3.8>
})
test:do_execsql2_test(
"join-1.3.9",
[[
SELECT aaa.*, bbb.* FROM t2 AS aaa NATURAL JOIN t1 AS bbb
]], {
-- <join-1.3.9>
"B", 2, "C", 3, "D", 4, "A", 1, "B", 2, "C", 3, "B", 3, "C", 4, "D", 5, "A", 2, "B", 3, "C", 4
-- </join-1.3.9>
})
test:do_execsql2_test(
"join-1.3.10",
[[
SELECT t1.*, t2.* FROM t2 NATURAL JOIN t1
]], {
-- <join-1.3.10>
"A", 1, "B", 2, "C", 3, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "B", 3, "C", 4, "D", 5
-- </join-1.3.10>
})
test:do_execsql2_test(
"join-1.4.1",
[[
SELECT * FROM t1 INNER JOIN t2 USING(b,c);
]], {
-- <join-1.4.1>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.4.1>
})
test:do_execsql2_test(
"join-1.4.2",
[[
SELECT * FROM t1 AS x INNER JOIN t2 USING(b,c);
]], {
-- <join-1.4.2>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.4.2>
})
test:do_execsql2_test(
"join-1.4.3",
[[
SELECT * FROM t1 INNER JOIN t2 AS y USING(b,c);
]], {
-- <join-1.4.3>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.4.3>
})
test:do_execsql2_test(
"join-1.4.4",
[[
SELECT * FROM t1 AS x INNER JOIN t2 AS y USING(b,c);
]], {
-- <join-1.4.4>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.4.4>
})
test:do_execsql_test(
"join-1.4.5",
[[
SELECT b FROM t1 JOIN t2 USING(b);
]], {
-- <join-1.4.5>
2, 3
-- </join-1.4.5>
})
-- Ticket #3522
test:do_execsql2_test(
"join-1.4.6",
[[
SELECT t1.* FROM t1 JOIN t2 USING(b);
]], {
-- <join-1.4.6>
"A", 1, "B", 2, "C", 3, "A", 2, "B", 3, "C", 4
-- </join-1.4.6>
})
test:do_execsql2_test(
"join-1.4.7",
[[
SELECT t2.* FROM t1 JOIN t2 USING(b);
]], {
-- <join-1.4.7>
"B", 2, "C", 3, "D", 4, "B", 3, "C", 4, "D", 5
-- </join-1.4.7>
})
test:do_execsql2_test(
"join-1.5",
[[
SELECT * FROM t1 INNER JOIN t2 USING(b);
]], {
-- <join-1.5>
"A", 1, "B", 2, "C", 3, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "C", 4, "D", 5
-- </join-1.5>
})
test:do_execsql2_test(
"join-1.6",
[[
SELECT * FROM t1 INNER JOIN t2 USING(c);
]], {
-- <join-1.6>
"A", 1, "B", 2, "C", 3, "B", 2, "D", 4, "A", 2, "B", 3, "C", 4, "B", 3, "D", 5
-- </join-1.6>
})
test:do_execsql2_test(
"join-1.7",
[[
SELECT * FROM t1 INNER JOIN t2 USING(c,b);
]], {
-- <join-1.7>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5
-- </join-1.7>
})
test:do_execsql_test(
"join-1.8",
[[
SELECT * FROM t1 NATURAL CROSS JOIN t2;
]], {
-- <join-1.8>
1, 2, 3, 4, 2, 3, 4, 5
-- </join-1.8>
})
test:do_execsql_test(
"join-1.9",
[[
SELECT * FROM t1 CROSS JOIN t2 USING(b,c);
]], {
-- <join-1.9>
1, 2, 3, 4, 2, 3, 4, 5
-- </join-1.9>
})
test:do_execsql_test(
"join-1.10",
[[
SELECT * FROM t1 NATURAL INNER JOIN t2;
]], {
-- <join-1.10>
1, 2, 3, 4, 2, 3, 4, 5
-- </join-1.10>
})
test:do_execsql_test(
"join-1.11",
[[
SELECT * FROM t1 INNER JOIN t2 USING(b,c);
]], {
-- <join-1.11>
1, 2, 3, 4, 2, 3, 4, 5
-- </join-1.11>
})
test:do_execsql_test(
"join-1.12",
[[
SELECT * FROM t1 natural inner join t2;
]], {
-- <join-1.12>
1, 2, 3, 4, 2, 3, 4, 5
-- </join-1.12>
})
test:do_execsql2_test(
"join-1.13",
[[
SELECT * FROM t1 NATURAL JOIN
(SELECT b as c, c as d, d as e FROM t2) as t3
]], {
-- <join-1.13>
"A", 1, "B", 2, "C", 3, "D", 4, "E", 5
-- </join-1.13>
})
test:do_execsql2_test(
"join-1.14",
[[
SELECT * FROM (SELECT b as c, c as d, d as e FROM t2) as "tx"
NATURAL JOIN t1
]], {
-- <join-1.14>
"C", 3, "D", 4, "E", 5, "A", 1, "B", 2
-- </join-1.14>
})
test:do_execsql_test(
"join-1.15",
[[
CREATE TABLE t3(c INT primary key,d INT,e INT);
INSERT INTO t3 VALUES(2,3,4);
INSERT INTO t3 VALUES(3,4,5);
INSERT INTO t3 VALUES(4,5,6);
SELECT * FROM t3;
]], {
-- <join-1.15>
2, 3, 4, 3, 4, 5, 4, 5, 6
-- </join-1.15>
})
test:do_execsql_test(
"join-1.16",
[[
SELECT * FROM t1 natural join t2 natural join t3;
]], {
-- <join-1.16>
1, 2, 3, 4, 5, 2, 3, 4, 5, 6
-- </join-1.16>
})
test:do_execsql2_test(
"join-1.17",
[[
SELECT * FROM t1 natural join t2 natural join t3;
]], {
-- <join-1.17>
"A", 1, "B", 2, "C", 3, "D", 4, "E", 5, "A", 2, "B", 3, "C", 4, "D", 5, "E", 6
-- </join-1.17>
})
test:do_execsql_test(
"join-1.18",
[[
CREATE TABLE t4(d INT primary key,e INT,f INT);
INSERT INTO t4 VALUES(2,3,4);
INSERT INTO t4 VALUES(3,4,5);
INSERT INTO t4 VALUES(4,5,6);
SELECT * FROM t4;
]], {
-- <join-1.18>
2, 3, 4, 3, 4, 5, 4, 5, 6
-- </join-1.18>
})
test:do_execsql_test(
"join-1.19.1",
[[
SELECT * FROM t1 natural join t2 natural join t4;
]], {
-- <join-1.19.1>
1, 2, 3, 4, 5, 6
-- </join-1.19.1>
})
test:do_execsql2_test(
"join-1.19.2",
[[
SELECT * FROM t1 natural join t2 natural join t4;
]], {
-- <join-1.19.2>
"A", 1, "B", 2, "C", 3, "D", 4, "E", 5, "F", 6
-- </join-1.19.2>
})
test:do_execsql_test(
"join-1.20",
[[
SELECT * FROM t1 natural join t2 natural join t3 WHERE t1.a=1
]], {
-- <join-1.20>
1, 2, 3, 4, 5
-- </join-1.20>
})
test:do_execsql_test(
"join-2.1",
[[
SELECT * FROM t1 NATURAL LEFT JOIN t2;
]], {
-- <join-2.1>
1, 2, 3, 4, 2, 3, 4, 5, 3, 4, 5, ""
-- </join-2.1>
})
-- ticket #3522
test:do_execsql2_test(
"join-2.1.1",
[[
SELECT * FROM t1 NATURAL LEFT JOIN t2;
]], {
-- <join-2.1.1>
"A", 1, "B", 2, "C", 3, "D", 4, "A", 2, "B", 3, "C", 4, "D", 5, "A", 3, "B", 4, "C", 5, "D", NULL,
-- </join-2.1.1>
})
test:do_execsql2_test(
"join-2.1.2",
[[
SELECT t1.* FROM t1 NATURAL LEFT JOIN t2;
]], {
-- <join-2.1.2>
"A", 1, "B", 2, "C", 3, "A", 2, "B", 3, "C", 4, "A", 3, "B", 4, "C", 5
-- </join-2.1.2>
})
test:do_execsql2_test(
"join-2.1.3",
[[
SELECT t2.* FROM t1 NATURAL LEFT JOIN t2;
]], {
-- <join-2.1.3>
"B", 2, "C", 3, "D", 4, "B", 3, "C", 4, "D", 5, "B", NULL, "C", NULL, "D", NULL,
-- </join-2.1.3>
})
test:do_execsql_test(
"join-2.2",
[[
SELECT * FROM t2 NATURAL LEFT OUTER JOIN t1;
]], {
-- <join-2.2>
1, 2, 3, "", 2, 3, 4, 1, 3, 4, 5, 2
-- </join-2.2>
})
test:do_catchsql_test(
"join-2.3",
[[
SELECT * FROM t1 NATURAL RIGHT OUTER JOIN t2;
]], {
-- <join-2.3>
1, "Tarantool does not support RIGHT and FULL OUTER JOINs"
-- </join-2.3>
})
test:do_execsql_test(
"join-2.4",
[[
SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d
]], {
-- <join-2.4>
1, 2, 3, "", "", "", 2, 3, 4, "", "", "", 3, 4, 5, 1, 2, 3
-- </join-2.4>
})
test:do_execsql_test(
"join-2.5",
[[
SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t1.a>1
]], {
-- <join-2.5>
2, 3, 4, "", "", "", 3, 4, 5, 1, 2, 3
-- </join-2.5>
})
test:do_execsql_test(
"join-2.6",
[[
SELECT * FROM t1 LEFT JOIN t2 ON t1.a=t2.d WHERE t2.b IS NULL OR t2.b>1
]], {
-- <join-2.6>
1, 2, 3, "", "", "", 2, 3, 4, "", "", ""
-- </join-2.6>
})
test:do_catchsql_test(
"join-3.1",
[[
SELECT * FROM t1 NATURAL JOIN t2 ON t1.a=t2.b;
]], {
-- <join-3.1>
1, "a NATURAL join may not have an ON or USING clause"
-- </join-3.1>
})
test:do_catchsql_test(
"join-3.2",
[[
SELECT * FROM t1 NATURAL JOIN t2 USING(b);
]], {
-- <join-3.2>
1, "a NATURAL join may not have an ON or USING clause"
-- </join-3.2>
})
test:do_catchsql_test(
"join-3.3",
[[
SELECT * FROM t1 JOIN t2 ON t1.a=t2.b USING(b);
]], {
-- <join-3.3>
1, "cannot have both ON and USING clauses in the same join"
-- </join-3.3>
})
test:do_catchsql_test(
"join-3.4.1",
[[
SELECT * FROM t1 JOIN t2 USING(a);
]], {
-- <join-3.4.1>
1, "cannot join using column A - column not present in both tables"
-- </join-3.4.1>
})
test:do_catchsql_test(
"join-3.4.2",
[[
SELECT * FROM t1 JOIN t2 USING(d);
]], {
-- <join-3.4.2>
1, "cannot join using column D - column not present in both tables"
-- </join-3.4.2>
})
test:do_catchsql_test(
"join-3.5",
[[
SELECT * FROM t1 USING(a)
]], {
-- <join-3.5>
1, "Syntax error at line 1 at or near position 40: a JOIN clause is required before ON and USING"
-- </join-3.5>
})
test:do_catchsql_test(
"join-3.6",
[[
SELECT * FROM t1 JOIN t2 ON t3.a=t2.b;
]], {
-- <join-3.6>
1, "Field 'A' was not found in space 'T3' format"
-- </join-3.6>
})
test:do_catchsql_test(
"join-3.7",
[[
SELECT * FROM t1 INNER OUTER JOIN t2;
]], {
-- <join-3.7>
1, "unknown or unsupported join type: INNER OUTER"
-- </join-3.7>
})
test:do_catchsql_test(
"join-3.8",
[[
SELECT * FROM t1 INNER OUTER CROSS JOIN t2;
]], {
-- <join-3.8>
1, "unknown or unsupported join type: INNER OUTER CROSS"
-- </join-3.8>
})
test:do_catchsql_test(
"join-3.9",
[[
SELECT * FROM t1 OUTER NATURAL INNER JOIN t2;
]], {
-- <join-3.9>
1, "unknown or unsupported join type: OUTER NATURAL INNER"
-- </join-3.9>
})
test:do_catchsql_test(
"join-3.10",
[[
SELECT * FROM t1 LEFT BOGUS JOIN t2;
]], {
-- <join-3.10>
1, "unknown or unsupported join type: LEFT BOGUS"
-- </join-3.10>
})
test:do_catchsql_test(
"join-3.11",
[[
SELECT * FROM t1 INNER BOGUS CROSS JOIN t2;
]], {
-- <join-3.11>
1, "unknown or unsupported join type: INNER BOGUS CROSS"
-- </join-3.11>
})
test:do_catchsql_test(
"join-3.12",
[[
SELECT * FROM t1 NATURAL AWK SED JOIN t2;
]], {
-- <join-3.12>
1, "unknown or unsupported join type: NATURAL AWK SED"
-- </join-3.12>
})
-- do_test join-4.1 {
-- execsql {
-- BEGIN;
-- CREATE TABLE t5(a INTEGER PRIMARY KEY);
-- CREATE TABLE t6(a INTEGER);
-- INSERT INTO t6 VALUES(NULL);
-- INSERT INTO t6 VALUES(NULL);
-- INSERT INTO t6 SELECT * FROM t6;
-- INSERT INTO t6 SELECT * FROM t6;
-- INSERT INTO t6 SELECT * FROM t6;
-- INSERT INTO t6 SELECT * FROM t6;
-- INSERT INTO t6 SELECT * FROM t6;
-- INSERT INTO t6 SELECT * FROM t6;
-- COMMIT;
-- }
-- execsql {
-- SELECT * FROM t6 NATURAL JOIN t5;
-- }
-- } {}
-- do_test join-4.2 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a<t5.a;
-- }
-- } {}
-- do_test join-4.3 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a>t5.a;
-- }
-- } {}
-- do_test join-4.4 {
-- execsql {
-- UPDATE t6 SET a='xyz';
-- SELECT * FROM t6 NATURAL JOIN t5;
-- }
-- } {}
-- do_test join-4.6 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a<t5.a;
-- }
-- } {}
-- do_test join-4.7 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a>t5.a;
-- }
-- } {}
-- do_test join-4.8 {
-- execsql {
-- UPDATE t6 SET a=1;
-- SELECT * FROM t6 NATURAL JOIN t5;
-- }
-- } {}
-- do_test join-4.9 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a<t5.a;
-- }
-- } {}
-- do_test join-4.10 {
-- execsql {
-- SELECT * FROM t6, t5 WHERE t6.a>t5.a;
-- }
-- } {}
test:do_execsql_test(
"join-5.1",
[[
create table centros (id integer primary key, centro TEXT);
create table usuarios (id integer primary key, nombre TEXT, apellidos TEXT,
idcentro integer);
START TRANSACTION;
INSERT INTO centros VALUES(1,'xxx');
INSERT INTO usuarios VALUES(1,'a','aa',1);
INSERT INTO usuarios VALUES(2,'b','bb',1);
INSERT INTO usuarios VALUES(3,'c','cc',NULL);
COMMIT;
create index idcentro on usuarios (idcentro);
select usuarios.id, usuarios.nombre, centros.centro from
usuarios left outer join centros on usuarios.idcentro = centros.id;
]], {
-- <join-5.1>
-- query plan changed because scan estimated cost changed for tarantool
--3, "c", "", 1, "a", "xxx", 2, "b", "xxx"
1,"a","xxx",2,"b","xxx",3,"c",""
-- </join-5.1>
})
-- A test for ticket #247.
--
test:do_execsql_test(
"join-7.1",
[[
CREATE TABLE t7 (id INT primary key, x TEXT, y INT);
INSERT INTO t7 VALUES (1, 'pa1', 1);
INSERT INTO t7 VALUES (2, 'pa2', NULL);
INSERT INTO t7 VALUES (3, 'pa3', NULL);
INSERT INTO t7 VALUES (4, 'pa4', 2);
INSERT INTO t7 VALUES (5, 'pa30', 131);
INSERT INTO t7 VALUES (6, 'pa31', 130);
INSERT INTO t7 VALUES (7, 'pa28', NULL);
CREATE TABLE t8 (a integer primary key, b TEXT);
INSERT INTO t8 VALUES (1, 'pa1');
INSERT INTO t8 VALUES (2, 'pa4');
INSERT INTO t8 VALUES (3, NULL);
INSERT INTO t8 VALUES (4, NULL);
INSERT INTO t8 VALUES (130, 'pa31');
INSERT INTO t8 VALUES (131, 'pa30');
SELECT coalesce(t8.a,999) from t7 LEFT JOIN t8 on y=a;
]], {
-- <join-7.1>
1, 999, 999, 2, 131, 130, 999
-- </join-7.1>
})
-- MUST_WORK_TEST
-- # Make sure a left join where the right table is really a view that
-- # is itself a join works right. Ticket #306.
-- #
-- ifcapable view {
-- do_test join-8.1 {
-- execsql {
-- BEGIN;
-- CREATE TABLE t9(a INTEGER PRIMARY KEY, b INT);
-- INSERT INTO t9 VALUES(1,11);
-- INSERT INTO t9 VALUES(2,22);
-- CREATE TABLE t10(x INTEGER PRIMARY KEY, y INT);
-- INSERT INTO t10 VALUES(1,2);
-- INSERT INTO t10 VALUES(3,3);
-- CREATE TABLE t11(p INTEGER PRIMARY KEY, q INT);
-- INSERT INTO t11 VALUES(2,111);
-- INSERT INTO t11 VALUES(3,333);
-- CREATE VIEW v10_11 AS SELECT x, q FROM t10, t11 WHERE t10.y=t11.p;
-- COMMIT;
-- SELECT * FROM t9 LEFT JOIN v10_11 ON( a=x );
-- }
-- } {1 11 1 111 2 22 {} {}}
-- ifcapable subquery {
-- do_test join-8.2 {
-- execsql {
-- SELECT * FROM t9 LEFT JOIN (SELECT x, q FROM t10, t11 WHERE t10.y=t11.p)
-- ON( a=x);
-- }
-- } {1 11 1 111 2 22 {} {}}
-- }
-- do_test join-8.3 {
-- execsql {
-- SELECT * FROM v10_11 LEFT JOIN t9 ON( a=x );
-- }
-- } {1 111 1 11 3 333 {} {}}
-- ifcapable subquery {
-- # Constant expressions in a subquery that is the right element of a
-- # LEFT JOIN evaluate to NULL for rows where the LEFT JOIN does not
-- # match. Ticket #3300
-- do_test join-8.4 {
-- execsql {
-- SELECT * FROM t9 LEFT JOIN (SELECT 44, p, q FROM t11) AS sub1 ON p=a
-- }
-- } {1 11 {} {} {} 2 22 44 2 111}
-- }
-- } ;# ifcapable view
-- Ticket #350 describes a scenario where LEFT OUTER JOIN does not
-- function correctly if the right table in the join is really
-- subquery.
--
-- To test the problem, we generate the same LEFT OUTER JOIN in two
-- separate selects but with on using a subquery and the other calling
-- the table directly. Then connect the two SELECTs using an EXCEPT.
-- Both queries should generate the same results so the answer should
-- be an empty set.
--
test:do_execsql_test(
"join-9.1",
[[
CREATE TABLE t12(a INT primary key,b INT);
CREATE TABLE t13(b INT primary key,c INT);
START TRANSACTION;
INSERT INTO t12 VALUES(1,11);
INSERT INTO t12 VALUES(2,22);
INSERT INTO t13 VALUES(22,222);
COMMIT;
]], {
-- <join-9.1>
-- </join-9.1>
})
test:do_execsql_test(
"join-9.1.1",
[[
SELECT * FROM t12 NATURAL LEFT JOIN t13
EXCEPT
SELECT * FROM t12 NATURAL LEFT JOIN (SELECT * FROM t13 WHERE b>0);
]], {
-- <join-9.1.1>
-- </join-9.1.1>
})
-- MUST_WORK_TEST
-- ifcapable view {
-- do_test join-9.2 {
-- execsql {
-- CREATE VIEW v13 AS SELECT * FROM t13 WHERE b>0;
-- SELECT * FROM t12 NATURAL LEFT JOIN t13
-- EXCEPT
-- SELECT * FROM t12 NATURAL LEFT JOIN v13;
-- }
-- } {}
-- } ;# ifcapable view
-- ifcapable compound
-- Ticket #1697: Left Join WHERE clause terms that contain an
-- aggregate subquery.
--
test:do_execsql_test(
"join-10.1",
[[
CREATE TABLE t21(a INT primary key,b INT,c INT);
CREATE TABLE t22(p INT primary key,q INT);
CREATE INDEX i22 ON t22(q);
SELECT a FROM t21 LEFT JOIN t22 ON b=p WHERE q=
(SELECT max(m.q) FROM t22 m JOIN t21 n ON n.b=m.p WHERE n.c=1);
]], {
-- <join-10.1>
-- </join-10.1>
})
-- Test a LEFT JOIN when the right-hand side of hte join is an empty
-- sub-query. Seems fine.
--
test:do_test(
"join-10.2",
function()
test:execsql [[
CREATE TABLE t23(a INT primary key, b INT, c INT);
CREATE TABLE t24(a INT primary key, b INT, c INT);
INSERT INTO t23 VALUES(1, 2, 3);
]]
return test:execsql [[
SELECT * FROM t23 LEFT JOIN t24;
]]
end, {
-- <join-10.2>
1, 2, 3, "", "", ""
-- </join-10.2>
})
test:do_execsql_test(
"join-10.3",
[[
SELECT * FROM t23 LEFT JOIN (SELECT * FROM t24);
]], {
-- <join-10.3>
1, 2, 3, "", "", ""
-- </join-10.3>
})
-- ifcapable subquery
---------------------------------------------------------------------------
-- The following tests are to ensure that bug b73fb0bd64 is fixed.
--
test:do_test(
"join-11.1",
function()
test:execsql [[
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
]]
return test:execsql [[
CREATE TABLE t1(a INTEGER PRIMARY KEY, b TEXT);
CREATE TABLE t2(a INTEGER PRIMARY KEY, b TEXT);
INSERT INTO t1 VALUES(1,'abc');
INSERT INTO t1 VALUES(2,'def');
INSERT INTO t2 VALUES(1,'abc');
INSERT INTO t2 VALUES(2,'def');
SELECT * FROM t1 NATURAL JOIN t2;
]]
end, {
-- <join-11.1>
1, "abc", 2, "def"
-- </join-11.1>
})
test:do_execsql_test(
"join-11.2",
[[
SELECT a FROM t1 JOIN t1 USING (a)
]], {
-- <join-11.2>
1, 2
-- </join-11.2>
})
test:do_execsql_test(
"join-11.3",
[[
SELECT a FROM t1 JOIN t1 AS t2 USING (a)
]], {
-- <join-11.3>
1, 2
-- </join-11.3>
})
test:do_execsql_test(
"join-11.3",
[[
SELECT * FROM t1 NATURAL JOIN t1 AS t2
]], {
-- <join-11.3>
1, "abc", 2, "def"
-- </join-11.3>
})
test:do_execsql_test(
"join-11.4",
[[
SELECT * FROM t1 NATURAL JOIN t1
]], {
-- <join-11.4>
1, "abc", 2, "def"
-- </join-11.4>
})
test:do_test(
"join-11.5",
function()
test:execsql [[
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
]]
return test:execsql [[
CREATE TABLE t1(id INT primary key, a TEXT COLLATE "unicode_ci", b INT);
CREATE TABLE t2(id INT primary key, a TEXT, b INT);
INSERT INTO t1 VALUES(1, 'ONE', 1);
INSERT INTO t1 VALUES(2, 'two', 2);
INSERT INTO t2 VALUES(1, 'one', 1);
INSERT INTO t2 VALUES(2, 'two', 2);
]]
end, {
-- <join-11.5>
-- </join-11.5>
})
-- MUST_WORK_TEST
-- do_test join-11.6 {
-- execsql { SELECT a,b FROM t1 NATURAL JOIN t2 }
-- } {ONE 1 two 2}
test:do_execsql_test(
"join-11.7",
[[
SELECT a,b FROM t2 NATURAL JOIN t1
]], {
-- <join-11.7>
"one", 1, "two", 2
-- </join-11.7>
})
test:do_test(
"join-11.8",
function()
test:execsql [[
DROP TABLE IF EXISTS t1;
DROP TABLE IF EXISTS t2;
]]
return test:execsql [[
CREATE TABLE t1(a TEXT primary key, b TEXT);
CREATE TABLE t2(b INTEGER primary key, a TEXT);
INSERT INTO t1 VALUES('one', '1');
INSERT INTO t1 VALUES('two', '2');
INSERT INTO t2 VALUES(1, 'one');
INSERT INTO t2 VALUES(2, 'two');
]]
end, {
-- <join-11.8>
-- </join-11.8>
})
test:do_execsql_test(
"join-11.9",
[[
SELECT * FROM t1 NATURAL JOIN t2
]], {
-- <join-11.9>
"one", "1", "two", "2"
-- </join-11.9>
})
test:do_execsql_test(
"join-11.10",
[[
SELECT * FROM t2 NATURAL JOIN t1
]], {
-- <join-11.10>
1, "one", 2, "two"
-- </join-11.10>
})
---------------------------------------------------------------------------
-- Test that at most 64 tables are allowed in a join.
--
test:do_execsql_test(
"join-12.1",
[[
CREATE TABLE t14(x TEXT primary key);
INSERT INTO t14 VALUES('abcdefghij');
]])
local function jointest(tn, nTbl, res)
sql = "SELECT 1 FROM "..string.rep("t14,", (nTbl - 1)).." t14;"
test:do_catchsql_test(tn, sql, res)
-- X(685, "X!cmd", [=[["uplevel",[["list","do_catchsql_test",["tn"],["sql"],["res"]]]]]=])
end
jointest("join-12.2", 30, {0, {1}})
jointest("join-12.3", 63, {0, {1}})
jointest("join-12.4", 64, {0, {1}})
jointest("join-12.5", 65, {1, 'The number of tables in a join 65 exceeds the limit (64)'})
jointest("join-12.6", 66, {1, 'The number of tables in a join 66 exceeds the limit (64)'})
jointest("join-12.7", 127, {1, 'The number of tables in a join 127 exceeds the limit (64)'})
jointest("join-12.8", 128, {1, 'The number of tables in a join 128 exceeds the limit (64)'})
jointest("join-12.9", 1000, {1, 'The number of tables in a join 1000 exceeds the limit (64)'})
jointest("join-12.10", 65534, {1, 'The number of tables in a join 65534 exceeds the limit (64)'})
jointest("join-12.11", 65535, {1, 'The number of tables in a join 65535 exceeds the limit (64)'})
jointest("join-12.12", 65536, {1, 'The number of tables in a join 65536 exceeds the limit (64)'})
jointest("join-12.13", 65537, {1, 'The number of tables in a join 65537 exceeds the limit (64)'})
-- end
--end
---------------------------------------------------------------------------
-- Test a problem with reordering tables following a LEFT JOIN.
--
test:do_execsql_test(
"join-13.0",
[[
CREATE TABLE aa(a INT primary key);
CREATE TABLE bb(b INT primary key);
CREATE TABLE cc(id INT primary key, c INT);
INSERT INTO aa VALUES(45);
INSERT INTO cc VALUES(1, 45);
INSERT INTO cc VALUES(2, 45);
]])
test:do_execsql_test(
"join-13.1",
[[
SELECT a,b,c FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
]], {
-- <join-13.1>
45, "", 45, 45, "", 45
-- </join-13.1>
})
-- In the following, the order of [cc] and [bb] must not be exchanged, even
-- though this would be helpful if the query used an inner join.
test:do_execsql_test(
"join-13.2",
[[
CREATE INDEX ccc ON cc(c);
SELECT a,b,c FROM aa LEFT JOIN bb, cc WHERE cc.c=aa.a;
]], {
-- <join-13.2>
45, "", 45, 45, "", 45
-- </join-13.2>
})
test:finish_test()
|