summaryrefslogtreecommitdiff
path: root/mysql-test/main/range_vs_index_merge.test
blob: a8e86e44b9eaf186d079d90652f83fadbed6a4bc (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
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
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
--source include/default_optimizer_switch.inc
--source include/default_charset.inc
--source include/have_sequence.inc

set names utf8;

CREATE DATABASE world;

use world;

--source include/world_schema.inc

--disable_query_log
--disable_result_log
--disable_warnings
--source include/world.inc
--enable_warnings
--enable_result_log
--enable_query_log

SELECT COUNT(*) FROM Country;
SELECT COUNT(*) FROM City;
SELECT COUNT(*) FROM CountryLanguage;

CREATE INDEX Name ON City(Name);

--disable_query_log
--disable_result_log
--disable_warnings
ANALYZE TABLE City;
--enable_warnings
--enable_result_log
--enable_query_log

set session optimizer_switch='index_merge_sort_intersection=off';

# The following 4 queries are added for code coverage 

#the exptected # of rows differ on 32-bit and 64-bit platforms for innodb 
--replace_column 9 4079
EXPLAIN
SELECT * FROM City
  WHERE (Population >= 100000 OR Name LIKE 'P%' OR Population < 100000);

EXPLAIN
SELECT * FROM City
  WHERE (Population >= 100000 OR Name LIKE 'P%') AND Country='CAN' OR
        (Population < 100000 OR Name Like 'T%') AND Country='ARG';

EXPLAIN
SELECT * FROM City
  WHERE Population < 200000 AND Name LIKE 'P%' AND
        (Population > 300000 OR Name LIKE 'T%') AND
        (Population < 100000 OR Name LIKE 'Pa%');

EXPLAIN
SELECT * FROM City
  WHERE Population > 100000 AND Name LIKE 'Aba%' OR
        Country IN ('CAN', 'ARG') AND  ID BETWEEN 120 AND 130 OR
        Country <= 'ALB' AND Name LIKE 'L%' OR
        ID BETWEEN 3807 AND 3810;

# The output of the next 3 commands tells us about selectivities
# of the conditions utilized in 2 queries following after them  

EXPLAIN 
SELECT * FROM City
  WHERE (Population > 101000 AND Population < 115000);

EXPLAIN 
SELECT * FROM City
  WHERE (Population > 101000 AND Population < 102000);

EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'));

# The pattern of the WHERE condition used in the following 2 queries is
#   (range(key1) OR range(key2)) AND range(key3)
# Varying values of the constants in the second conjunct of the condition
# we can get either a plan with range index scan for key3 or a plan with
# an index merge retrieval over key2 and key3

EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 115000);

EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 102000);

# The following 4 queries check that the plans
# for the previous 2 plans are valid

SELECT * FROM City USE INDEX ()
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 115000);

SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 115000);

SELECT * FROM City USE INDEX ()
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 102000);

SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'F'))
        AND (Population > 101000 AND Population < 102000);

# The output of the next 7 commands tells us about selectivities
# of the conditions utilized in 4 queries following after them  

EXPLAIN
SELECT  * FROM City WHERE (Name < 'Ac');
EXPLAIN
SELECT  * FROM City WHERE (Name < 'Bb');
EXPLAIN
SELECT  * FROM City WHERE (Country > 'A' AND Country < 'B');
EXPLAIN
SELECT  * FROM City WHERE (Name BETWEEN 'P' AND 'Pb');
EXPLAIN
SELECT  * FROM City WHERE (Name BETWEEN 'P' AND 'S');
EXPLAIN
SELECT  * FROM City WHERE (Population > 101000 AND Population < 110000);
EXPLAIN
SELECT  * FROM City WHERE (Population > 103000 AND Population < 104000);

# The pattern of the WHERE condition used in the following 4 queries is
#   (range1(key1) AND range(key2)) OR (range2(key1) AND range(key3)
# Varying values of the constants in the range conjuncts of the condition
# we can get: 
#     1. a plan with range index over key1 
#   index merge retrievals over:
#     2. key1 and key3
#     3. key2 and key1
#     4. key2 and key3

EXPLAIN
SELECT  * FROM City 
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

EXPLAIN
SELECT  * FROM City
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));

EXPLAIN
SELECT  * FROM City
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

EXPLAIN
SELECT  * FROM City
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));

# The following 8 queries check that the plans
# for the previous 4 plans are valid

SELECT  * FROM City USE INDEX ()
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

SELECT  * FROM City 
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

SELECT  * FROM City USE INDEX ()
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));

SELECT  * FROM City
  WHERE (Name < 'Ac' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));

SELECT  * FROM City USE INDEX ()
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

SELECT  * FROM City
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'Pb' AND (Population > 101000 AND Population < 110000));

SELECT  * FROM City USE INDEX ()
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));

SELECT  * FROM City
  WHERE (Name < 'Bb' AND (Country > 'A' AND Country < 'B')) OR
  (Name BETWEEN 'P' AND 'S' AND (Population > 103000 AND Population < 104000));


# The output of the next 6 commands tells us about selectivities
# of the conditions utilized in 3 queries following after them  

EXPLAIN
SELECT * FROM City WHERE (ID < 10) OR (ID BETWEEN 100 AND 110);
EXPLAIN
SELECT * FROM City WHERE (ID < 200) OR (ID BETWEEN 100 AND 200);
EXPLAIN
SELECT * FROM City WHERE (ID < 600) OR (ID BETWEEN 900 AND 1500);
EXPLAIN
SELECT * FROM City WHERE Country > 'A' AND Country < 'ARG';
EXPLAIN
SELECT * FROM City WHERE Name LIKE 'H%' OR Name LIKE 'P%' ;
EXPLAIN
SELECT * FROM City WHERE Name LIKE 'Ha%' OR Name LIKE 'Pa%' ;

# The pattern of the WHERE condition used in the following 3 queries is
#   (range1(key1) AND (range1(key2) OR range(key3)) OR
#   (range2(key1) AND (range2(key2) OR range(key4))
# Varying values of the constants in the range predicates of the condition
# we can get: 
#     1. a plan with range index over key1 
#     2. an index merge retrieval over key1, key2 and key3

EXPLAIN
SELECT * FROM City
  WHERE ((ID < 10) AND (Name LIKE 'H%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 110) AND 
            (Name LIKE 'P%' OR (Population > 103000 AND Population < 104000)));

EXPLAIN
SELECT * FROM City
  WHERE ((ID < 800) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 900 AND 1500) AND 
            (Name LIKE 'Pa%' OR (Population > 103000 AND Population < 105000)));

EXPLAIN
SELECT * FROM City
  WHERE ((ID < 200) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 200) AND 
            (Name LIKE 'Pa%' OR (Population > 103200 AND Population < 104000)));


# The following 6 queries check that the plans
# for the previous 3 plans are valid

SELECT * FROM City USE INDEX ()
  WHERE ((ID < 10) AND (Name LIKE 'H%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 110) AND 
            (Name LIKE 'P%' OR (Population > 103000 AND Population < 104000)));

SELECT * FROM City
  WHERE ((ID < 10) AND (Name LIKE 'H%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 110) AND 
            (Name LIKE 'P%' OR (Population > 103000 AND Population < 104000)));

SELECT * FROM City USE INDEX()
  WHERE ((ID < 800) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 900 AND 1500) AND 
            (Name LIKE 'Pa%' OR (Population > 103000 AND Population < 104000)));

SELECT * FROM City
  WHERE ((ID < 800) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 900 AND 1500) AND 
            (Name LIKE 'Pa%' OR (Population > 103000 AND Population < 104000)));

SELECT * FROM City USE INDEX ()
  WHERE ((ID < 200) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 200) AND 
            (Name LIKE 'Pa%' OR (Population > 103000 AND Population < 104000)));

SELECT * FROM City
  WHERE ((ID < 200) AND (Name LIKE 'Ha%' OR (Country > 'A' AND Country < 'ARG')))
        OR ((ID BETWEEN 100 AND 200) AND 
            (Name LIKE 'Pa%' OR (Population > 103000 AND Population < 104000)));


# The output of the next 8 commands tells us about selectivities
# of the conditions utilized in 2 queries following after them  

EXPLAIN 
SELECT * FROM City WHERE Population > 101000 AND Population < 102000;
EXPLAIN 
SELECT * FROM City WHERE Population > 101000 AND Population < 110000;
EXPLAIN 
SELECT * FROM City WHERE Country < 'C';
EXPLAIN 
SELECT * FROM City WHERE Country < 'AGO';
EXPLAIN 
SELECT * FROM City WHERE Name BETWEEN 'P' AND 'S';
EXPLAIN 
SELECT * FROM City WHERE Name BETWEEN 'P' AND 'Pb';
EXPLAIN 
SELECT * FROM City WHERE ID BETWEEN 3400 AND 3800;
EXPLAIN 
SELECT * FROM City WHERE ID BETWEEN 3790 AND 3800;
EXPLAIN 
SELECT * FROM City WHERE Name LIKE 'P%';

# The pattern of the WHERE condition used in the following 2 queries is
#   (range(key1) AND (range1(key2) OR range1(key3)) OR
#   (range(key4) AND (range2(key2) OR range2(key3))
# Varying values of the constants in the range predicates of the condition
# we can get:  
#   index merge retrievals over:
#     1. key1, key2 and key3
#     2. key4, key2 and key3

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) AND
         (Country < 'C' OR Name BETWEEN 'P' AND 'S')) OR
        ((ID BETWEEN 3400 AND 3800) AND 
         (Country < 'AGO' OR Name LIKE 'Pa%'));

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 110000) AND
         (Country < 'AGO' OR Name BETWEEN 'P' AND 'Pb')) OR
        ((ID BETWEEN 3790 AND 3800) AND 
         (Country < 'C' OR Name LIKE 'P%'));

# The following 4 queries check that the plans
# for the previous 2 plans are valid

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 102000) AND
         (Country < 'C' OR Name BETWEEN 'P' AND 'S')) OR
        ((ID BETWEEN 3400 AND 3800) AND 
         (Country < 'AGO' OR Name LIKE 'Pa%'));

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) AND
         (Country < 'C' OR Name BETWEEN 'P' AND 'S')) OR
        ((ID BETWEEN 3400 AND 3800) AND 
         (Country < 'AGO' OR Name LIKE 'Pa%'));

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 110000) AND
         (Country < 'AGO' OR Name BETWEEN 'P' AND 'Pb')) OR
        ((ID BETWEEN 3790 AND 3800) AND 
         (Country < 'C' OR Name LIKE 'P%'));

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 110000) AND
         (Country < 'AGO' OR Name BETWEEN 'P' AND 'Pb')) OR
        ((ID BETWEEN 3790 AND 3800) AND 
         (Country < 'C' OR Name LIKE 'P%'));


CREATE INDEX CountryPopulation ON City(Country,Population);

--disable_query_log
--disable_result_log
--disable_warnings
ANALYZE TABLE City;
--enable_warnings
--enable_result_log
--enable_query_log

# The output of the next 5 commands tells us about selectivities
# of the conditions utilized in 2 queries following after them  

EXPLAIN
SELECT * FROM City WHERE Name LIKE 'Pas%';
EXPLAIN
SELECT * FROM City WHERE Name LIKE 'P%';
EXPLAIN
SELECT * FROM City WHERE (Population > 101000 AND Population < 103000);
EXPLAIN
SELECT * FROM City WHERE Country='USA';
EXPLAIN
SELECT * FROM City WHERE Country='FIN';

# The pattern of the WHERE condition used in the following 3 queries is
#   (range(key1_p2) OR (range(key2)) AND key1_p1=c
# Varying values of the constants in the range predicates of the condition
# we can get: 
#     1. a plan with range index over key1_p1 
#     2. an index merge retrieval over: key1 and key2

EXPLAIN
SELECT * FROM City 
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'Pas%')
        AND Country='USA';

EXPLAIN
SELECT * FROM City 
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'P%')
        AND Country='EST';

# The following 4 queries check that the plans
# for the previous 2 plans are valid

SELECT * FROM City 
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'Pas%')
        AND Country='USA';

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'Pas%')
        AND Country='USA';

SELECT * FROM City 
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'P%')
        AND Country='FIN';

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 103000) OR Name LIKE 'P%')
        AND Country='FIN';


CREATE INDEX CountryName ON City(Country,Name);

--disable_query_log
--disable_result_log
--disable_warnings
ANALYZE TABLE City;
--enable_warnings
--enable_result_log
--enable_query_log

# The output of the next 12 commands tells us about selectivities
# of the conditions utilized in 3 queries following after them  

EXPLAIN
SELECT * FROM City WHERE Country='USA';
EXPLAIN
SELECT * FROM City WHERE Country='FIN';
EXPLAIN
SELECT * FROM City WHERE Country='BRA';
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 3790 AND 3800;
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 4025 AND 4035;
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 4028 AND 4032;
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 3500 AND 3800;
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 4000 AND 4300;
EXPLAIN
SELECT * FROM City WHERE ID BETWEEN 250 and 260 ;
EXPLAIN
SELECT * FROM City WHERE (Population > 101000 AND Population < 102000);
EXPLAIN
SELECT * FROM City WHERE (Population > 101000 AND Population < 103000);
EXPLAIN
SELECT * FROM City WHERE Name LIKE 'Pa%';

# The pattern of the WHERE condition used in the following 3 queries is
#   (range(key1_p2) OR range1(key3)) AND
#    range(key1|2_p1=c) AND 
#   (range(key2_p2) OR range2(key3))
# Varying values of the constants in the range conjuncts of the condition
# we can get: 
#     1. a plan with range index over key1|2_p1 
#   index merge retrievals over:
#     2. key1 and key3
#     3. key2 and key3
set @tmp_range_vs_index_merge=@@optimizer_switch;
set optimizer_switch='extended_keys=off';

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4025 AND 4035);

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 103000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4028 AND 4032);

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 110000) OR
          ID BETWEEN 3500 AND 3800) AND Country='FIN'
        AND (Name BETWEEN 'P' AND 'T' OR ID BETWEEN 4000 AND 4300);

# The following 6 queries check that the plans
# for the previous 3 plans are valid

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4025 AND 4035);

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4025 AND 4035);

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4028 AND 4032);

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4028 AND 4032);

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='FIN'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4025 AND 4035);

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='FIN'
        AND (Name LIKE 'Pa%' OR ID BETWEEN 4025 AND 4035);


# The pattern of the WHERE condition used in the following query is
#   (range(key1_p2) OR range1(key3)) AND range(key1|2_p1=c1) AND 
#   (range(key2_p2) OR range1(key3)) AND range(key1|2_p1=c2)
# We get an index merge retrieval over key1, key2 and key3 for it

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 and Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        OR (Name LIKE 'Pa%' OR ID BETWEEN 250 AND 260) AND Country='BRA';

# The following 2 queries check that the plans
# for the previous plan is valid

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 and Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        OR (Name LIKE 'Pa%' OR ID BETWEEN 250 AND 260) AND Country='BRA';

SELECT * FROM City
  WHERE ((Population > 101000 and Population < 102000) OR
          ID BETWEEN 3790 AND 3800) AND Country='USA'
        OR (Name LIKE 'Pa%' OR ID BETWEEN 250 AND 260) AND Country='BRA';

# The pattern of the WHERE condition used in the following query is
#   (impossible_range(key1_p2) OR range1(key3)) AND
#    range(key1|2_p1=c1) AND 
#   (range(key2_p2) OR range2(key3)) 
# where range1(key3) and range2(key3) are disjoint 
# Varying values of the constant in range predicates we get plans:
#   1. with an index scan over key2 
#   2. with an index scan over key4=key2_p2

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'P%' OR ID BETWEEN 4000 AND 4300);

EXPLAIN
SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pho%' OR ID BETWEEN 4000 AND 4300);

# The following 4 queries check that the plans
# for the previous 2 plans are valid

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'P%' OR ID BETWEEN 4000 AND 4300);

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'P%' OR ID BETWEEN 4000 AND 4300);

SELECT * FROM City USE INDEX ()
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pho%' OR ID BETWEEN 4000 AND 4300);

SELECT * FROM City
  WHERE ((Population > 101000 AND Population < 11000) OR
          ID BETWEEN 3500 AND 3800) AND Country='USA'
        AND (Name LIKE 'Pho%' OR ID BETWEEN 4000 AND 4300);


DROP INDEX Population ON City;
DROP INDEX Name ON City;
set optimizer_switch=@tmp_range_vs_index_merge;

# The pattern of the WHERE condition used in the following query is
#   (key1|2_p1=c AND range(key1_p2)) OR (key1|2_p1=c AND range(key2_p2))
# We get an index merge retrieval over key1, key2 for it

EXPLAIN
SELECT * FROM City
  WHERE Country='USA' AND Population BETWEEN 101000 AND 102000 OR
        Country='USA' AND Name LIKE 'Pa%';

# The following 2 queries check that the plans
# for the previous plan is valid

SELECT * FROM City USE INDEX()
  WHERE Country='USA' AND Population BETWEEN 101000 AND 102000 OR
        Country='USA' AND Name LIKE 'Pa%';

SELECT * FROM City
  WHERE Country='USA' AND Population BETWEEN 101000 AND 102000 OR
        Country='USA' AND Name LIKE 'Pa%';


# The pattern of the WHERE condition used in the following query is
#   key1|2_p1=c AND (range(key1_p2) OR range(key2_p2))
# We get an index merge retrieval over key1, key2 for it

EXPLAIN
SELECT * FROM City
  WHERE Country='USA' AND 
        (Population BETWEEN 101000 AND 102000 OR Name LIKE 'Pa%');

# The following 2 queries check that the plans
# for the previous plan is valid

SELECT * FROM City
  WHERE Country='USA' AND 
        (Population BETWEEN 101000 AND 102000 OR Name LIKE 'Pa%');

SELECT * FROM City
  WHERE Country='USA' AND 
        (Population BETWEEN 101000 AND 102000 OR Name LIKE 'Pa%');


#
# LP bug #954262: index merge over long disjunction in WHERE    
#  

set @save_optimizer_switch=@@optimizer_switch;

CREATE INDEX CityName on City(Name);  

let $cond =
(Name='Manila' AND Country='PHL') OR
(Name='Addis Abeba' AND Country='ETH') OR          
(Name='Jakarta' AND Country='IDN') OR  
(Name='Bangalore' AND Country='IND') OR
(Name='Teheran' AND Country='IRN') OR          
(Name='Roma' AND Country='ITA') OR  
(Name='Delhi' AND Country='IND') OR  
(Name='Venezia' AND Country='ITA') OR  
(Name='Tokyo' AND Country='JPN') OR
(Name='Toronto' AND Country='CAN') OR  
(Name='Peking' AND Country='CHN') OR  
(Name='Lagos' AND Country='NGA') OR  
(Name='Tijuana' AND Country='MEX') OR
(Name='Rabat' AND Country='MAR') OR          
(Name='Seoul' AND Country='KOR') OR  
(Name='Vancouver' AND Country='CAN') OR  
(Name='Kaunas' AND Country='LTU') OR  
(Name='Paris' AND Country='FRA') OR
(Name='Dakar' AND Country='SEN') OR          
(Name='Basel' AND Country='CHE') OR  
(Name='Praha' AND Country='CZE') OR  
(Name='Ankara' AND Country='TUR') OR  
(Name='Dresden' AND Country='DEU') OR
(Name='Lugansk' AND Country='UKR') OR          
(Name='Caracas' AND Country='VEN') OR  
(Name='Samara' AND Country='RUS') OR  
(Name='Seattle' AND Country='USA');

eval
EXPLAIN SELECT Name, Country, Population FROM City WHERE
$cond;
--sorted_result
eval 
SELECT Name, Country, Population FROM City WHERE
$cond;

set optimizer_switch='index_merge=off';

eval
EXPLAIN SELECT Name, Country, Population FROM City WHERE
$cond;
--sorted_result
eval
SELECT Name, Country, Population FROM City WHERE
$cond;

set optimizer_switch=@save_optimizer_switch;

--echo # 
--echo # Bug mdev-585: range vs index-merge with ORDER BY ... LIMIT n
--echo # (LP bug #637962)
--echo # 

DROP INDEX CountryPopulation ON City;
DROP INDEX CountryName ON City;
DROP INDEX CityName on City;

CREATE INDEX Name ON City(Name);
CREATE INDEX Population ON City(Population);


--replace_column 9 #
EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000);
FLUSH STATUS;
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000);
SHOW STATUS LIKE 'Handler_read_%';


--replace_column 9 #
EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;

FLUSH STATUS;
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;
SHOW STATUS LIKE 'Handler_read_%';

set @tmp_mdev585=@@optimizer_use_condition_selectivity;
set optimizer_use_condition_selectivity=1;
--replace_column 9 #
EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;

FLUSH STATUS;
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;
SHOW STATUS LIKE 'Handler_read_%';

set optimizer_use_condition_selectivity=@tmp_mdev585;

set optimizer_switch='index_merge=off';

--replace_column 9 #
EXPLAIN 
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;

FLUSH STATUS;
SELECT * FROM City
  WHERE ((Name > 'Ca' AND Name < 'Cf') OR (Country > 'E' AND Country < 'H'))
        AND (Population >= 100000 AND Population < 120000)
ORDER BY Population LIMIT 5;
SHOW STATUS LIKE 'Handler_read_%';

set optimizer_switch=@save_optimizer_switch;
          

DROP DATABASE world;

use test;

#
# Bug #17259: a bad range scan and a good index merge plan
#

CREATE TABLE t1 (
  id int(10) unsigned NOT NULL auto_increment,
  account_id int(10) unsigned NOT NULL,
  first_name varchar(50) default NULL,
  middle_name varchar(50) default NULL,
  last_name  varchar(100) default NULL,
  home_address_1 varchar(150) default NULL,
  home_city varchar(75) default NULL,
  home_state char(2) default NULL,
  home_postal_code varchar(50) default NULL,
  home_county varchar(75) default NULL,
  home_country char(3) default NULL,
  work_address_1 varchar(150) default NULL,
  work_city varchar(75) default NULL,
  work_state char(2) default NULL,
  work_postal_code varchar(50) default NULL,
  work_county varchar(75) default NULL,
  work_country char(3) default NULL,
  login varchar(50) NOT NULL,
  PRIMARY KEY  (id),
  KEY login (login,account_id),
  KEY account_id (account_id),
  KEY user_home_country_indx (home_country),
  KEY user_work_country_indx (work_country),
  KEY user_home_state_indx (home_state),
  KEY user_work_state_indx (work_state),
  KEY user_home_city_indx (home_city),
  KEY user_work_city_indx (work_city),
  KEY user_first_name_indx (first_name),
  KEY user_last_name_indx (last_name)
);

insert into t1(account_id, login, home_state, work_state) values
  (1, 'pw', 'ia', 'ia'), (1, 'pw', 'ia', 'ia'), (1, 'pw', 'ia', 'ia'),
  (1, 'pw', 'ia', 'ia'), (1, 'pw', 'ia', 'ia'), (1, 'pw', 'ia', 'ia');
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;
insert into t1(account_id, login, home_state, work_state)
  select 1, 'pw', 'ak', 'ak' from t1;

analyze table t1;

select count(*) from t1 where account_id = 1;

select * from t1
  where (home_state = 'ia' or work_state='ia') and account_id = 1;

explain
select * from t1
  where (home_state = 'ia' or work_state='ia') and account_id = 1;

drop table t1;

#
# Bug #17673: no index merge plan if the condition for the last used
#             index component is factored out of the or formula  
#

CREATE TABLE t1 (
  c1 int(11) NOT NULL auto_increment,
  c2 decimal(10,0) default NULL,
  c3 decimal(10,0) default NULL,
  c4 decimal(10,0) default NULL,
  c5 decimal(10,0) default NULL,
  cp decimal(1,0) default NULL,
  ce decimal(10,0) default NULL,
  cdata char(20),
  PRIMARY KEY  (c1),
  KEY k1 (c2,c3,cp,ce),
  KEY k2 (c4,c5,cp,ce)
);

insert into t1 (c2, c3, c4, c5, cp) values(1,1,1,1,1);
insert into t1 (c2, c3, c4, c5, cp) values(2,1,1,1,4);
insert into t1 (c2, c3, c4, c5, cp) values(2,1,2,1,1);
insert into t1 (c2, c3, c4, c5, cp) values(2,1,3,1,4);
insert into t1 (c2, c3, c4, c5, cp) values(3,1,4,1,4);

insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;
insert into t1 (c2, c3, c4, c5, cp)
  select c2, c3, c4, c5, cp from t1 where cp = 4;

analyze table t1;

explain
  select * from t1 where (c2=1 and c3=1) or (c4=2 and c5=1);

explain
  select * from t1
    where (c2=1 and c3=1 and cp=1) or (c4=2 and c5=1 and cp=1);

explain
  select * from t1
    where ((c2=1 and c3=1) or (c4=2 and c5=1)) and cp=1;

select * from t1
  where (c2=1 and c3=1 and cp=1) or (c4=2 and c5=1 and cp=1);

select * from t1
  where ((c2=1 and c3=1) or (c4=2 and c5=1)) and cp=1;

drop table t1;

#
# Bug #23322: a bad range scan and a good index merge plan
#

create table t1 (
  c1 int auto_increment primary key,
  c2 char(20),
  c3 char (20), 
  c4 int
);
alter table t1 add key k1 (c2);
alter table t1 add key k2 (c3);
alter table t1 add key k3 (c4);

insert into t1 values(null, 'a', 'b', 0);
insert into t1 values(null, 'c', 'b', 0);
insert into t1 values(null, 'a', 'd', 0);
insert into t1 values(null, 'ccc', 'qqq', 0);

insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';
insert into t1 (c2,c3) select c2,c3 from t1 where c2 != 'a';

insert into t1 (c2,c3,c4) select c2,c3,1 from t1 where c2 != 'a';
insert into t1 (c2,c3,c4) select c2,c3,2 from t1 where c2 != 'a';
insert into t1 (c2,c3,c4) select c2,c3,3 from t1 where c2 != 'a';
insert into t1 (c2,c3,c4) select c2,c3,4 from t1 where c2 != 'a';

analyze table t1;

select count(*) from t1 where (c2='e' OR c3='q');
select count(*) from t1 where c4 != 0;

explain
  select distinct c1 from t1 where (c2='e' OR c3='q');

explain
  select distinct c1 from t1 where (c4!= 0) AND (c2='e' OR c3='q');

drop table t1;

#
# Bug #30151: a bad range scan and a good index merge plan
#

create table t1 (
  id int unsigned auto_increment primary key,
  c1 char(12),
  c2 char(15),
  c3 char(1)
);

insert into t1 (c3) values ('1'), ('2');

insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;
insert into t1 (c3) select c3 from t1;

update t1 set c1=lpad(id+1000, 12, ' '), c2=lpad(id+10000, 15, ' ');

alter table t1 add unique index (c1), add unique index (c2), add index (c3);

analyze table t1;

explain
  select * from t1 where (c1='      100000' or c2='         2000000');
explain
  select * from t1 where (c1='      100000' or c2='         2000000') and c3='2';

select * from t1 where (c1='      100000' or c2='         2000000');
select * from t1 where (c1='      100000' or c2='         2000000') and c3='2';

drop table t1;

#
# Bug #637978: invalid index merge access plan causes to wrong results
#

CREATE TABLE t1 (
  a smallint DEFAULT NULL,
  pk int NOT NULL AUTO_INCREMENT PRIMARY KEY,
  b varchar(10) DEFAULT NULL,
  c varchar(64) DEFAULT NULL,
  INDEX idx1 (a),
  INDEX idx2 (b),
  INDEX idx3 (c)
);
--disable_query_log
--disable_result_log
INSERT INTO t1 VALUES
(30371,99001,'dl','e'),(3,99002,'Ohio','t'),(9,99003,'Delaware','xb'),
(0,99004,'Pennsylvan','i'),(-199,99005,'y','d'),(0,99006,'with','Rhode Island'),
(3,99007,'km','qkmiimdxbdljsejtsfrvwlrgacinbmfuosflnenlpomkmvbig'),
(22860,99008,'ovqkmiimdx','uovqkmiimdxbdljsejtsfrvwlrgacinbmfuosflnenlpomkmvbig'),
(212,99009,'f','p'),(NULL,99010,'i','k'),(20426,99011,'Vermont','New York'),
(0,99012,'Oregon','w'),(31831,99013,'s','isrcijpuovqkmiimdxbdljsejtsfrvwl'),
(123,99014,'t','p'),(32767,99015,'q','Maine'),
(NULL,99016,'know','qqqpisrcijpuovqkmiimdxbdljsejtsfrvwlrgacinbmfuosflnenlpo'),
(1,99017,'going','North Carolina'),(-717,99018,'ad','Indiana'),
(32767,99019,'Maryland','aa'),(31280,99020,'Nebraska','Colorado'),
(0,99021,'q','Ohio'),
(5989,99022,'rovaadtqqq','lrovaadtqqqpisrcijpuovqkmiimdxbdljsejtsfrvwlrgacinb'),
(89,99023,'n','Pennsylvania'),(0,99024,'Florida','c'),(97,99025,'Maine','y'),
(149,99026,'xaemnl','Idaho'),(NULL,99027,'h','y'),(26276,99028,'going','New York'),
(242,99029,'bdhxaemnlr','sbdhxaemnlrovaadtqqqpisrcijpuovqkmiimdxb'),
(32767,99030,'if','a'),(26581,99031,'Arizona','q'),(45,99032,'ysazsbdhxa','f'),
(0,99033,'qv','s'),(NULL,99034,'Louisiana','lqvfysazsbdhxaemnlrovaadtqqqpisrc'),
(160,99035,'Connecticu','x'),(23241,99036,'lx','q'),(0,99037,'u','Colorado'),
(-19141,99038,'w','h'),(218,99039,'s','uo'),(4,99040,'Montana','Oklahoma'),
(97,99041,'r','ls'),(32767,99042,'q','v'),(7,99043,'mlsuownlnl','did'),
(NULL,99044,'ui','i'),(2,99045,'to','I\'ll'),(0,99046,'Nevada','g'),
(3251,99047,'y','New York'),(0,99048,'wyttuimlsu','you\'re'),
(7,99049,'he','South Carolina'),(32767,99050,'s','right'),
(172,99051,'Arizona','e'),(0,99052,'x','lxmvwyttuimlsuownlnlxklq'),
(NULL,99053,'f','wfjlxmvwyttuimlsuownlnlxklqvfysazs'),(44,99054,'s','n'),
(-17561,99055,'me','wm'),(88,99056,'y','my'),(7313,99057,'jx','New Hampshire'),
(63,99058,'zl','South Carolina'),(9,99059,'ma','Illinois'),
(6,99060,'lamazljxpg','like'),(17021,99061,'x','v'),(0,99062,'New Mexico','j'),
(179,99427,'fliq','because'),
(107,99063,'Virginia','Mississippi'),
(0,99064,'si','to'),(113,99065,'Illinois','Kansas'),(20808,99066,'tsi','d'),
(-15372,99067,'d','vdftsidjtvulamazljxpgiwmbnmwfjlxmvwyttuimlsuownlnl'),
(0,99068,'y','then'),(2,99069,'all','b'),(NULL,99070,'by','Wisconsin'),
(4,99071,'about','right'),(5,99072,'m','s'),(0,99073,'e','Pennsylvania'),
(-28284,99074,'x','f'),(1,99075,'Rhode Isla','Georgia'),(NULL,99076,'p','was'),
(168,99077,'Tennessee','Minnesota'),(18349,99078,'x','Rhode Island'),
(5,99079,'as','d'),(12217,99080,'c','i'),(0,99081,'rdvdxboydm','s'),
(19132,99082,'her','jerdvdxboydmpefbiesqbyyvdftsidjtvulamazljxpgiwmbn'),
(0,99083,'all','jhjerdvdxboydmpefbiesqbyyvdftsidjtvulamazljx'),
(32767,99084,'s','flj'),(-4947,99085,'something','Vermont'),
(0,99086,'cjfljhjerd','Washington');

ANALYZE TABLE t1;
--enable_query_log
--enable_result_log

SELECT COUNT(*) FROM t1 IGNORE INDEX (idx2,idx3)
  WHERE c  = 'i'  OR b IN ( 'Arkansas' , 'd' , 'pdib' , 'can' )  OR
  (pk BETWEEN 120 AND 79 + 255 OR a IN ( 4 , 179 , 1 ) ) AND a > 8 ;
SELECT COUNT(*) FROM t1 
  WHERE c  = 'i'  OR b IN ( 'Arkansas' , 'd' , 'pdib' , 'can' )  OR
  (pk BETWEEN 120 AND 79 + 255 OR a IN ( 4 , 179 , 1 ) ) AND a > 8 ;
EXPLAIN
SELECT COUNT(*) FROM t1 
  WHERE c  = 'i'  OR b IN ( 'Arkansas' , 'd' , 'pdib' , 'can' )  OR
  (pk BETWEEN 120 AND 79 + 255 OR a IN ( 4 , 179 , 1 ) ) AND a > 8 ;

DROP TABLE t1;

#
# Bug #684117: ORing of two index merge that caused a crash
#

CREATE TABLE t1 (
  f1 int, f2 int, f3 int, f4 int, f5 int,
  PRIMARY KEY (f4), KEY (f1), KEY (f2), KEY (f3)
) ;
INSERT INTO t1 VALUES (0,0,NULL,9,5), (0,0,1,9425,NULL);

SELECT f5 FROM t1
  WHERE f2 != 1 OR f1 IS NULL OR f4 = 4 OR
        f2 AND (f4 BETWEEN 6 AND 255 OR f3 IS NULL);

DROP TABLE t1;
 
#
# Bug #685952: An invalid index merge union plan
#

CREATE TABLE t1 (
  f1 int, f2 int, f3 int, f4 int,
  PRIMARY KEY (f1), KEY (f3), KEY (f4)
);

INSERT INTO t1 VALUES (1,0,0,0), (2,0,0,0), (3,0,0,0);
INSERT INTO t1 VALUES (9,0,2,6), (9930,0,0,NULL);
insert into t1 select seq,seq,seq,seq from seq_100_to_400;

analyze table t1;

SET SESSION optimizer_switch='index_merge_intersection=off';
SET SESSION optimizer_switch='index_merge_sort_union=off';

SET SESSION optimizer_switch='index_merge_union=off';

EXPLAIN
SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SET SESSION optimizer_switch='index_merge_union=on';

EXPLAIN
SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );


INSERT INTO t1 VALUES 
  (93,0,3,6), (9933,0,3,3), (94,0,4,6), (9934,0,4,4),
  (95,0,5,6), (9935,0,5,5), (96,0,6,6), (9936,0,6,6),
  (97,0,7,6), (9937,0,7,7), (98,0,8,6), (9938,0,8,8),
  (99,0,9,6), (9939,0,9,9);

analyze table t1;

SET SESSION optimizer_switch='index_merge_union=off';

EXPLAIN
SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SET SESSION optimizer_switch='index_merge_union=on';

EXPLAIN
SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SELECT * FROM t1 FORCE KEY (PRIMARY,f3,f4)
  WHERE ( f3 = 1 OR f1 = 7 ) AND f1 < 10
        OR f3 BETWEEN 2 AND 2 AND ( f3 = 1 OR f4 < 7 );

SET SESSION optimizer_switch=DEFAULT;

DROP TABLE t1;

#
# Bug #752353: valgrind complain on a jump depending 
#             on an uninitialised value 
#

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

CREATE TABLE t2 (f1 int, f2 int, f3 int, f4 int, INDEX idx (f3,f2)) ;
INSERT INTO t2 VALUES (5,6,0,0), (0,4,0,0);

CREATE TABLE t3 (f1 int, f2 int, INDEX idx1 (f2,f1) , INDEX idx2 (f1)) ;
INSERT INTO t3 VALUES (6,0),( 4,0);

SELECT * FROM t1,t2,t3
  WHERE (t2.f3 = 1 OR t3.f1=t2.f1) AND t3.f1 <> t2.f2 AND t3.f2 = t2.f4; 

DROP TABLE t1,t2,t3;

#
# LP bug #823301: index merge sort union with possible index scan  
#              

CREATE TABLE t1 (
  a int, b int, c int, d int,
  PRIMARY KEY(b), INDEX idx1(d), INDEX idx2(d,b,c)
);
INSERT INTO t1 VALUES 
 (0,58,7,7),(0,63,2,0),(0,64,186,8),(0,65,1,-2), (0,71,190,-3),
 (0,72,321,-7),(0,73,0,3),(0,74,5,25),(0,75,5,3);

ANALYZE TABLE t1;

SET SESSION optimizer_switch='index_merge_sort_union=off';
EXPLAIN
SELECT * FROM t1 
  WHERE t1.b>7 AND t1.d>1 AND t1.d<>8  OR t1.d>=7 AND t1.d<8 OR t1.d>7;
SELECT * FROM t1 
  WHERE t1.b>7 AND t1.d>1 AND t1.d<>8  OR t1.d>=7 AND t1.d<8 OR t1.d>7;
SET SESSION optimizer_switch='index_merge_sort_union=on';
EXPLAIN
SELECT * FROM t1 
  WHERE t1.b>7 AND t1.d>1 AND t1.d<>8  OR t1.d>=7 AND t1.d<8 OR t1.d>7;
SELECT * FROM t1 
  WHERE t1.b>7 AND t1.d>1 AND t1.d<>8  OR t1.d>=7 AND t1.d<8 OR t1.d>7;
SET SESSION optimizer_switch=DEFAULT;

DROP TABLE t1;

#
# LP bug #800184: possible index merge sort union   
#              

CREATE TABLE t1 (a int NOT NULL PRIMARY KEY, b int, c int, INDEX idx(c,b));
INSERT INTO t1 VALUES (19,1,NULL), (20,5,7);

EXPLAIN
SELECT * FROM t1
  WHERE t1.a>300 AND t1.c!=0 AND t1.b>=350 AND t1.b<=400 AND
       (t1.c=0 OR t1.a=500);
SELECT * FROM t1
  WHERE t1.a>300 AND t1.c!=0 AND t1.b>=350 AND t1.b<=400 AND
       (t1.c=0 OR t1.a=500);

DROP TABLE t1;

#
# LP bug #891953: always true OR    
#              

CREATE TABLE t1 (a int PRIMARY KEY, b int, INDEX idx(b));
INSERT INTO t1 VALUES (167,9999), (168,10000);

EXPLAIN
SELECT * FROM t1
  WHERE a BETWEEN 4 AND 5 AND b IN (255,4) OR a IN (2,14,25) OR (a<2 or a>2);
SELECT * FROM t1
  WHERE a BETWEEN 4 AND 5 AND b IN (255,4) OR a IN (2,14,25) OR (a<2 or a>2);

DROP TABLE t1;


--echo #
--echo # MDEV-8603: Wrong result OR/AND condition over index fields
--echo #

CREATE TABLE t1 (
  id INT NOT NULL,
  state VARCHAR(64),
  capital VARCHAR(64),
  UNIQUE KEY (id),
  KEY state (state,id),
  KEY capital (capital, id)
);
 
INSERT INTO t1 VALUES  
  (1,'Arizona','Phoenix'), 
  (2,'Hawaii','Honolulu'),
  (3,'Georgia','Atlanta'), 
  (4,'Florida','Tallahassee'), 
  (5,'Alaska','Juneau'),
  (6,'Michigan','Lansing'),
  (7,'Pennsylvania','Harrisburg'),
  (8,'Virginia','Richmond')
;

ANALYZE TABLE t1;
 
EXPLAIN
SELECT * FROM t1 FORCE KEY (state,capital) 
WHERE ( state = 'Alabama' OR state >= 'Colorado' ) AND (id<9 or id>9) 
   OR ( capital >= 'Topeka' OR state = 'Kansas' ) AND state != 'Texas';
SELECT * FROM t1 FORCE KEY (state,capital) 
WHERE ( state = 'Alabama' OR state >= 'Colorado' ) AND (id<9 or id>9)
   OR ( capital >= 'Topeka' OR state = 'Kansas' ) AND state != 'Texas';

DROP TABLE t1;

--echo #
--echo # mdev-11574: do not build index merge of two indexes when
--echo #             one index is an infix of the other index
--echo #

set names utf8;

CREATE DATABASE world;

use world;

--source include/world_schema.inc

--disable_query_log
--disable_result_log
--disable_warnings
--source include/world.inc
--enable_warnings
--enable_result_log
--enable_query_log

DROP INDEX Country ON City;
CREATE INDEX CountryName ON City(Country,Name);
CREATE INDEX Name ON City(Name);

--disable_query_log
--disable_result_log
--disable_warnings
ANALYZE TABLE City;
--enable_warnings
--enable_result_log
--enable_query_log

let $q=
select * from City
where
 Country='FIN' AND Name IN ('Lahti','Imatra') OR
 Country='RUS' AND Name IN ('St Petersburg', 'Moscow') OR
 Country='SWE' AND Name IN ('Stockholm', 'Uppsala') OR
 Country='DEU' AND Name IN ('Berlin', 'Bonn') OR
 Country='BEL' AND Name IN ('Antwerpen', 'Gent') OR
 Country='PRT' AND Name IN ('Braga', 'Porto') OR
 Country='FRA' AND Name IN ('Paris', 'Marcel') OR
 Country='POL' AND Name IN ('Warszawa', 'Wroclaw') OR
 Country='NOR' AND Name IN ('Oslo', 'Bergen') OR
 Country='ITA' AND Name IN ('Napoli', 'Venezia');

eval $q;
eval explain $q;


DROP DATABASE world;

#the following command must be the last one in the file
set session optimizer_switch='index_merge_sort_intersection=default';