summaryrefslogtreecommitdiff
path: root/mysql-test/main/subselect_partial_match.test
blob: fd1e6de716c399b3c65bc7495eb8c8d872a270c5 (plain)
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
#
# Tests for
# MWL#68: Subquery optimization: Efficient NOT IN execution with NULLs
#

set @save_optimizer_switch=@@optimizer_switch;

--echo -------------------------------
--echo Part 1: Feature tests.
--echo -------------------------------

--echo Default for all tests.
set @@optimizer_switch = "materialization=on,in_to_exists=off,semijoin=off,subquery_cache=off";
set @test_default_opt_switch = @@optimizer_switch;
set @in_exists = "materialization=off,in_to_exists=on,semijoin=off,subquery_cache=off";

--echo -------------------------------------------------------------------------
--echo Schema requires partial matching, but data analysis discoveres there is
--echo no need. This is possible only if all outer columns are not NULL.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(8) not null, a2 char(8) not null);
create table t2 (b1 char(8), b2 char(8));

insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');

insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', NULL    );
insert into t2 values (NULL    , '2 - 02');
insert into t2 values (NULL    , NULL    );
insert into t2 values ('1 - 02', '2 - 02');

select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);

select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo NULLs in the outer columns, no NULLs in the suqbuery 
--echo -------------------------------------------------------------------------

create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8) not null, b2 char(8) not null);

insert into t1 values (NULL    , '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');
insert into t1 values (NULL    , NULL    );

insert into t2 values ('1 - 00', '2 - 00');
insert into t2 values ('1 - 01', '2 - 01');
insert into t2 values ('1 - 02', '2 - 00');

select * from t1
where (a1, a2) not in (select * from t2 where b1 is not null and b2 is not null);

select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2) in (select * from t2 where b1 is not null and b2 is not null);

select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo NULLs in the outer column, NULLs in the subquery, there is
--echo no value match in any column, but there is a partial match
--echo such that some of the matching NULLs are in the outer columns,
--echo the other NULLs are in the inner columns.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(1), a2 char(1), a3 char(1));
create table t2 (b1 char(1), b2 char(1), b3 char(1));

insert into t1 values ('c',  NULL, 'a');
insert into t2 values (NULL,  'x', NULL);
insert into t2 values (NULL,  'y', NULL);
insert into t2 values ('o',   'z', 'p');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch = @test_default_opt_switch;

drop table t1, t2;

create table t1 (a1 char(1), a2 char(1) not null, a3 char(1));
create table t2 (b1 char(1), b2 char(1),          b3 char(1));

insert into t1 values (NULL,  'y', NULL);
insert into t2 values ('v', 'x', NULL);
insert into t2 values (NULL, 'y', 'w');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch = @test_default_opt_switch;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo There is only one column in the subquery to complement the NULLs in the
--echo outer reference. It is a NULL column, so a match is guaranteed.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(1), a2 char(1), a3 char(1));
create table t2 (b1 char(1), b2 char(1), b3 char(1));

insert into t1 values (NULL,  'g', NULL);
insert into t2 values ('z',  NULL, 'y');
insert into t2 values (NULL, 'z', 'y');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch = @test_default_opt_switch;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo The intersection of the NULL bitmaps is empty because the ranges
--echo of NULL bits do not overlap.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(1), a2 char(1), a3 char(1));
create table t2 (b1 char(1), b2 char(1), b3 char(1));

insert into t1 values ('b',  'g', NULL);
insert into t2 values ('z',  NULL, 'y');
insert into t2 values (NULL, 'z', 'y');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3) NOT IN (select * from t2);

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo The intersection of the NULL bitmaps is non-empty, and there is a
--echo non-NULL column.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(1), a2 char(1), a3 char(1) not null, a4 char(10));
create table t2 (b1 char(1), b2 char(1), b3 char(1),          b4 char(1));

insert into t1 values ('a',  'g', 'x', NULL);
insert into t2 values ('z',  NULL, 'y', 'x');
insert into t2 values (NULL, NULL, 'x', 'y');
insert into t2 values ('x',  'w', 'z', NULL);

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo Value match in one row, but the NULL complement match in another.
--echo The result must be false.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(2), a2 char(1), a3 char(1) not null, a4 char(10));
create table t2 (b1 char(2), b2 char(1), b3 char(1),          b4 char(1));

insert into t1 values ('99',  NULL, 'j', 'f');

insert into t2 values ('01',  NULL, 'y', NULL);
insert into t2 values ('02',  NULL, 'x', 'y');
insert into t2 values ('03',  'q', 'y', 'x');
insert into t2 values (NULL,  'q', 'm', 'p');
insert into t2 values ('m', 'z', 'j', NULL);
insert into t2 values (NULL, 'z', 'b', NULL);
insert into t2 values (NULL, 'z', 'a', NULL);
insert into t2 values ('34',  'q', 'y', 'x');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo Test the intersection of larger number of rows with NULL, such that
--echo the number is at the boundary 32. This test is based on the implementation
--echo of MY_BITMAP which uses 32 bit words, and the intersection operation works
--echo by intersecting the bitmap word by word.
--echo -------------------------------------------------------------------------

create table t1 (a1 char(2), a2 char(2), a3 char(1), a4 char(10)) ENGINE=MyISAM;
create table t2 (b1 char(2), b2 char(2), b3 char(1), b4 char(1)) ENGINE=MyISAM;

insert into t1 values (NULL, '98', NULL, 'b');
insert into t1 values (NULL, '99', NULL, 'c');

insert into t2 values ('00',  'rr', 'y', NULL);
insert into t2 values ('01',  'rr', 'y', NULL);
insert into t2 values ('02',  NULL, 'x', 'y');
insert into t2 values ('03',  'qq', 'y', 'x');
insert into t2 values ('04',  'qq', 'm', 'p');
insert into t2 values ('05',  'rr', 'y', NULL);
insert into t2 values ('06',  NULL, 'x', 'y');
insert into t2 values ('07',  'qq', 'y', 'x');
insert into t2 values ('08',  'qq', 'm', 'q');
insert into t2 values ('09',  'rr', 'y', NULL);
insert into t2 values ('10',  NULL, 'x', 'y');
insert into t2 values ('11',  'qq', 'y', 'x');
insert into t2 values ('12',  'qq', 'm', 'k');
insert into t2 values ('13',  'rr', 'y', NULL);
insert into t2 values ('14',  NULL, 'x', 'y');
insert into t2 values ('15',  'qq', 'y', 'x');
insert into t2 values ('16',  'qq', 'm', 's');
insert into t2 values ('17',  'rr', 'y', NULL);
insert into t2 values ('18',  NULL, 'x', 'y');
insert into t2 values ('19',  'qq', 'y', 'x');
insert into t2 values ('20',  'qq', 'm', 't');
insert into t2 values ('21',  'rr', 'y', NULL);
insert into t2 values ('22',  NULL, 'x', 'y');
insert into t2 values ('23',  'qq', 'y', 'x');
insert into t2 values ('24',  'qq', 'm', 'u');
insert into t2 values ('25',  'rr', 'y', NULL);
insert into t2 values ('26',  NULL, 'x', 'y');
insert into t2 values ('27',  'qq', 'y', 'x');
insert into t2 values ('28',  'qq', 'm', 'y');
insert into t2 values ('29',  'rr', 'y', NULL);
insert into t2 values ('30',  NULL, 'x', 'z');
insert into t2 values ('31',  'ss', 'h', NULL);
insert into t2 values ('32',  'vv', 'i', NULL);
--echo the only partial matching row
insert into t2 values ('33',  NULL, 'j', NULL);
insert into t2 values ('34',  'qq', 'y', 'x');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

--echo change the mathcing row to be the last one in the first bitmap word
update t2 set b2 = 'zz' where b1 = 33;
update t2 set b2 = NULL where b1 = 31;

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch='partial_match_rowid_merge=off,partial_match_table_scan=on';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

set @@optimizer_switch=@in_exists;
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
EXPLAIN
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);
SELECT * from t1 where (a1, a2, a3, a4) NOT IN (select * from t2);

drop table t1, t2;


--echo -------------------------------------------------------------------------
--echo All columns require partial matching (no non-null columns)
--echo -------------------------------------------------------------------------

--echo TODO

--echo -------------------------------------------------------------------------
--echo Both non-NULL columns and columns with NULLs
--echo -------------------------------------------------------------------------

--echo TODO

--echo -------------------------------------------------------------------------
--echo Covering NULL rows
--echo -------------------------------------------------------------------------

create table t1 (a1 char(8), a2 char(8));
create table t2 (b1 char(8), b2 char(8));

insert into t1 values ('1 - 00', '2 - 00');
insert into t1 values ('1 - 01', '2 - 01');

insert into t2 values ('1 - 01', NULL    );
insert into t2 values (NULL    , '2 - 02');
insert into t2 values (NULL    , NULL    );
insert into t2 values ('1 - 02', '2 - 02');

select * from t1
where (a1, a2) not in (select * from t2);

select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;

insert into t2 values ('1 - 01', '2 - 01');

select * from t1
where (a1, a2) not in (select * from t2);

select a1, a2, (a1, a2) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2) in (select * from t2);

select a1, a2, (a1, a2) in (select * from t2) as in_res from t1;


drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo Covering NULL columns
--echo -------------------------------------------------------------------------

--echo this case affects only the rowid-merge algorithm
set @@optimizer_switch="partial_match_rowid_merge=on,partial_match_table_scan=off";

create table t1 (a1 char(8) not null, a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8) not null, b2 char(8), b3 char(8) not null);

insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');

insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values ('1 - 02', NULL, '3 - 02');
insert into t2 values ('1 - 00', NULL, '3 - 00');

select * from t1
where (a1, a2, a3) not in (select * from t2);

select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2, a3) in (select * from t2);

select *, (a1, a2, a3) in (select * from t2) as in_res from t1;

drop table t1, t2;

create table t1 (a1 char(8), a2 char(8), a3 char(8) not null);
create table t2 (b1 char(8), b2 char(8), b3 char(8) not null);

insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');

insert into t2 values (NULL, NULL, '3 - x1');
insert into t2 values (NULL, NULL, '3 - 02');
insert into t2 values (NULL, NULL, '3 - 00');

select * from t1
where (a1, a2, a3) not in (select * from t2);

select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2, a3) in (select * from t2);

select *, (a1, a2, a3) in (select * from t2) as in_res from t1;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo Covering NULL row, and a NULL column
--echo -------------------------------------------------------------------------

create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8),          b2 char(8), b3 char(8));

insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');

insert into t2 values ('1 - 01', NULL, '3 - x1');
insert into t2 values (NULL    , NULL, NULL    );
insert into t2 values ('1 - 00', NULL, '3 - 00');

select * from t1
where (a1, a2, a3) not in (select * from t2);

select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2, a3) in (select * from t2);

select *, (a1, a2, a3) in (select * from t2) as in_res from t1;

drop table t1, t2;


--echo -------------------------------------------------------------------------
--echo Covering NULL row, and covering NULL columns
--echo -------------------------------------------------------------------------

create table t1 (a1 char(8) not null, a2 char(8), a3 char(8));
create table t2 (b1 char(8),          b2 char(8), b3 char(8));

insert into t1 values ('1 - 00', '2 - 00', '3 - 00');
insert into t1 values ('1 - 01', '2 - 01', '3 - 01');

insert into t2 values (NULL, NULL, NULL);
insert into t2 values (NULL, NULL, NULL);

select * from t1
where (a1, a2, a3) not in (select * from t2);

select *, (a1, a2, a3) not in (select * from t2) as in_res from t1;

select * from t1
where (a1, a2, a3) in (select * from t2);

select *, (a1, a2, a3) in (select * from t2) as in_res from t1;

drop table t1, t2;

--echo -------------------------------------------------------------------------
--echo Small buffer for the rowid_merge partial match algorithm that forces
--echo reverting to table scan partial match.
--echo -------------------------------------------------------------------------

set @save_rowid_merge_buff_size = @@rowid_merge_buff_size;
set @@rowid_merge_buff_size = 0;

create table t1 (a1 char(2), a2 char(2), a3 char(1), a4 char(10));
create table t2 (b1 char(2), b2 char(2), b3 char(1), b4 char(1));

insert into t1 values (NULL, '98', NULL, 'b');
insert into t1 values (NULL, '99', NULL, 'c');

insert into t2 values ('00',  'rr', 'y', NULL);
insert into t2 values ('01',  'rr', 'y', NULL);
insert into t2 values ('02',  NULL, 'x', 'y');
insert into t2 values ('03',  'qq', 'y', 'x');

set @@optimizer_switch='partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;
SELECT t1.*, (a1, a2, a3, a4) IN (select * from t2) as in_res from t1;

drop table t1, t2;

set @@rowid_merge_buff_size = @save_rowid_merge_buff_size;


--echo -------------------------------
--echo Part 2: Test cases for bugs.
--echo -------------------------------

--disable_warnings
drop table if exists t1, t2;
--enable_warnings

--echo #
--echo # LP BUG#608744
--echo #
set @@optimizer_switch="materialization=on,semijoin=off,partial_match_rowid_merge=on,partial_match_table_scan=off";
create table t1 (a1 char(1), a2 char(1));
insert into t1 values (NULL, 'b');
create table t2 (b1 char(1), b2 char(2));
insert into t2 values ('a','b'), ('c', 'd');
select * from t1 where (a1, a2) NOT IN (select b1, b2 from t2);
drop table t1,t2;


--echo #
--echo # LP BUG#601156
--echo #

CREATE TABLE t1 (a1 int DEFAULT NULL, a2 int DEFAULT NULL);
INSERT INTO t1 VALUES (NULL,2);
INSERT INTO t1 VALUES (4,NULL);
CREATE TABLE t2 (b1 int DEFAULT NULL, b2 int DEFAULT NULL);
INSERT INTO t2 VALUES (6,NULL);
INSERT INTO t2 VALUES (NULL,0);

set @@optimizer_switch='materialization=on,semijoin=off,partial_match_rowid_merge=on,partial_match_table_scan=on';

set @tmp_optimizer_switch=@@optimizer_switch;
set optimizer_switch='derived_merge=off,derived_with_keys=off';
EXPLAIN EXTENDED
SELECT * FROM (SELECT * FROM t1 WHERE a1 NOT IN (SELECT b2 FROM t2)) table1;
set optimizer_switch=@tmp_optimizer_switch;

DROP TABLE t1, t2;

--echo #
--echo # LP BUG#613009 Crash in Ordered_key::get_field_idx
--echo #

set @@optimizer_switch='materialization=on,semijoin=off,partial_match_rowid_merge=on,partial_match_table_scan=off';

create table t1 (a1 char(3) DEFAULT NULL, a2 char(3) DEFAULT NULL);
insert into t1 values (NULL, 'a21'), (NULL, 'a22');
explain select * from t1 where (a1, a2) not in (select a1, a2 from t1);
select * from t1 where (a1, a2) not in (select a1, a2 from t1);
drop table t1;

--echo #
--echo # LP BUG#680058 void Ordered_key::add_key(rownum_t):
--echo # Assertion `key_buff_elements && cur_key_idx < key_buff_elements' failed
--echo #

create table t1 (f1 char(1), f2 char(1));
insert into t1 values ('t', '0'), ('0', 't');
create table t2 (f3 char(1), f4 char(1));
insert into t2 values ('t', NULL), ('t', NULL), ('d', 'y');

set @@optimizer_switch='materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off,semijoin=off';
select * from t1 where (f1, f2) not in (select * from t2);
drop table t1, t2;


--echo #
--echo # LP BUG#809245 Second assertion `bit < (map)->n_bits' with partial_match_merge
--echo #

CREATE TABLE t1 (d varchar(32)) ;
INSERT INTO t1 VALUES ('r');

CREATE TABLE t2 ( a int, c varchar(32)) ;
INSERT INTO t2 VALUES (5,'r');

CREATE TABLE t3 ( a int NOT NULL , d varchar(32)) ;
INSERT INTO t3 VALUES (10,'g');

set @@optimizer_switch='materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off,in_to_exists=off';

EXPLAIN SELECT *
FROM t1
WHERE (t1.d , t1.d) NOT IN (
        SELECT t3.d , t2.c
        FROM t3 LEFT JOIN t2 ON t3.a = t2.a);

SELECT *
FROM t1
WHERE (t1.d , t1.d) NOT IN (
        SELECT t3.d , t2.c
        FROM t3 LEFT JOIN t2 ON t3.a = t2.a);

set @@optimizer_switch='materialization=off,in_to_exists=on';

EXPLAIN SELECT *
FROM t1
WHERE (t1.d , t1.d) NOT IN (
        SELECT t3.d , t2.c
        FROM t3 LEFT JOIN t2 ON t3.a = t2.a);

SELECT *
FROM t1
WHERE (t1.d , t1.d) NOT IN (
        SELECT t3.d , t2.c
        FROM t3 LEFT JOIN t2 ON t3.a = t2.a);

drop table t1, t2, t3;

--echo #
--echo # LP BUG#809266 Diverging results with partial_match_rowid_merge=on
--echo #

CREATE TABLE t1 (c int) ;
INSERT INTO t1 VALUES (0),(0);

CREATE TABLE t2 (a int, b int) ;
INSERT INTO t2 VALUES (6,3), (9,NULL);

set @@optimizer_switch='materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off,in_to_exists=off';

EXPLAIN
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT b, a FROM t2);
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT b, a FROM t2);

EXPLAIN
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT a, b FROM t2);
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT a, b FROM t2);

set @@optimizer_switch='materialization=off,in_to_exists=on';

EXPLAIN
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT b, a FROM t2);
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT b, a FROM t2);

EXPLAIN
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT a, b FROM t2);
SELECT * FROM t1 WHERE (6, 4 ) NOT IN (SELECT a, b FROM t2);

drop table t1, t2;

--echo #
--echo # LP BUG#856152 Wrong result with NOT IN subquery and partial_match_rowid_merge
--echo #

CREATE TABLE t1 ( f1 integer NOT NULL , f2 integer) ;
INSERT INTO t1 VALUES (3,3),(48,NULL),(49,1);

CREATE TABLE t2 ( f3 int) ;
INSERT INTO t2 VALUES (5);

set @@optimizer_switch='in_to_exists=off,materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off';
EXPLAIN SELECT * FROM t2 WHERE ( 3 , 1 ) NOT IN ( SELECT f1 , f2 FROM t1 );
SELECT * FROM t2 WHERE ( 3 , 1 ) NOT IN ( SELECT f1 , f2 FROM t1 );

set @@optimizer_switch='in_to_exists=on,materialization=off';
EXPLAIN SELECT * FROM t2 WHERE ( 3 , 1 ) NOT IN ( SELECT f1 , f2 FROM t1 );
SELECT * FROM t2 WHERE ( 3 , 1 ) NOT IN ( SELECT f1 , f2 FROM t1 );

drop table t1, t2;

--echo #
--echo # LP BUG#869036 Wrong result with in_to_exists=ON and NOT IN
--echo #

create table outer_sq (f1 char(1), f2 char(1));
insert into outer_sq values (NULL, 'c'), ('g', 'c');

create table inner_sq (f3 char(1), f4 char(1));
insert into inner_sq values(null, 'i'), ('v', null);

--echo All three strategies below must produce the same result.

set @@optimizer_switch='in_to_exists=off,materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off';
SELECT outer_sq.*, (f1, f2) IN (select * from inner_sq) from outer_sq;
SELECT * from outer_sq where (f1, f2) NOT IN (select * from inner_sq);

set @@optimizer_switch='in_to_exists=off,materialization=on,partial_match_rowid_merge=off,partial_match_table_scan=on';
SELECT outer_sq.*, (f1, f2) IN (select * from inner_sq) from outer_sq;
SELECT * from outer_sq where (f1, f2) NOT IN (select * from inner_sq);

set @@optimizer_switch='in_to_exists=on,materialization=off';
SELECT outer_sq.*, (f1, f2) IN (select * from inner_sq) from outer_sq;
SELECT * from outer_sq where (f1, f2) NOT IN (select * from inner_sq);

drop table outer_sq, inner_sq;

--echo #
--echo # LP BUG#893486 Wrong result with partial_match_rowid_merge , NOT IN , NULLs
--echo #

CREATE TABLE t1 (a int, b int);
INSERT INTO t1 VALUES (0,NULL),(2,NULL);

CREATE TABLE t2 (c int, d int);
INSERT INTO t2 VALUES (2,3),(4,5),(6, NULL);

set @@optimizer_switch='materialization=on,partial_match_rowid_merge=on,partial_match_table_scan=off,in_to_exists=off';

EXPLAIN SELECT * FROM t1 WHERE (a, b) NOT IN (SELECT c, d FROM t2);
SELECT * FROM t1 WHERE (a, b) NOT IN (SELECT c, d FROM t2);
SELECT a, b, (a, b) NOT IN (SELECT c, d FROM t2) subq_res FROM t1;

EXPLAIN SELECT * FROM t1 WHERE (a, b) NOT IN (SELECT c, d FROM t2 WHERE d is not NULL);
SELECT * FROM t1 WHERE (a, b) NOT IN (SELECT c, d FROM t2 WHERE d is not NULL);
SELECT a, b, (a, b) NOT IN (SELECT c, d FROM t2 WHERE d is not NULL) subq_res FROM t1;

drop table t1,t2;

set @@optimizer_switch=@save_optimizer_switch;