@@ -175,6 +175,219 @@ func TestPartitionPruningForEQ(t *testing.T) {
175
175
require .Equal (t , 0 , res [0 ])
176
176
}
177
177
178
+ func TestCast4PartitionPruning (t * testing.T ) {
179
+ store := testkit .CreateMockStore (t )
180
+ tk := testkit .NewTestKit (t , store )
181
+
182
+ tk .MustExec ("use test" )
183
+ tk .MustExec (`drop table if exists t` )
184
+ tk .MustExec (`drop table if exists t_ts` )
185
+ tk .MustExec (`drop table if exists t_hash` )
186
+ tk .MustExec (`drop table if exists t_range_col` )
187
+ tk .MustExec ("drop table if exists t_range_col_v2" )
188
+
189
+ tk .MustExec (`create table t(a int, b int, c int) partition by range(a) (
190
+ partition p1 values less than (100),
191
+ partition p2 values less than (200),
192
+ partition pm values less than (MAXVALUE));` )
193
+ // case 1: range partition
194
+ // 1.1.1 test between castIntAsReal(int) and real
195
+ tk .MustQuery (`explain select * from t where a between "123" and "199";` ).Check (
196
+ testkit .Rows ("TableReader_7 8000.00 root partition:p2 data:Selection_6" ,
197
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 123), le(cast(test.t.a, double BINARY), 199)" ,
198
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
199
+ // MySQL explain:
200
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
201
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
202
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
203
+ //| 1 | SIMPLE | t | p2 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
204
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
205
+
206
+ // 1.1.2 test between castIntAsReal(int) and real
207
+ tk .MustQuery (`explain select * from t where a between "123.12" and "199.99";` ).Check (
208
+ testkit .Rows ("TableReader_7 8000.00 root partition:p2 data:Selection_6" ,
209
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 123.12), le(cast(test.t.a, double BINARY), 199.99)" ,
210
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
211
+ // MySQL explain:
212
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
213
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
214
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
215
+ //| 1 | SIMPLE | t | p2 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
216
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
217
+
218
+ // 1.1.3 test between castIntAsReal(int) and real
219
+ tk .MustQuery (`explain select * from t where a between "ddd" and "99";` ).Check (
220
+ testkit .Rows ("TableReader_7 8000.00 root partition:p1 data:Selection_6" ,
221
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 0), le(cast(test.t.a, double BINARY), 99)" ,
222
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
223
+ // MySQL explain:
224
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
225
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
226
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
227
+ //| 1 | SIMPLE | t | p1 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
228
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
229
+
230
+ // 1.1.4 test between castIntAsReal(int) and real
231
+ tk .MustQuery (`explain select * from t where a between "123.12" and cast("199.99" as decimal);` ).Check (
232
+ testkit .Rows ("TableReader_7 8000.00 root partition:p2,pm data:Selection_6" ,
233
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 123.12), le(cast(test.t.a, double BINARY), 200)" ,
234
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
235
+ // MySQL explain:
236
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
237
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
238
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
239
+ //| 1 | SIMPLE | t | p2,pm | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
240
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
241
+
242
+ // 1.2.1 test between castIntAsDecimal(int) and decimal
243
+ tk .MustQuery (`explain select * from t where a between 123.12 and 199.99;` ).Check (
244
+ testkit .Rows ("TableReader_7 8000.00 root partition:p2 data:Selection_6" ,
245
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, decimal(10,0) BINARY), 123.12), le(cast(test.t.a, decimal(10,0) BINARY), 199.99)" ,
246
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
247
+ // MySQL explain:
248
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
249
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
250
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
251
+ //| 1 | SIMPLE | t | p2 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
252
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
253
+
254
+ // case 2: range partition, but not support expression
255
+ tk .MustExec (`create table t_ts (report_updated timestamp) partition by range(unix_timestamp(report_updated)) (
256
+ partition p1 values less than (1732982400), -- 2024-12-01 00:00:00
257
+ partition p2 values less than (1733068800), -- 2024-12-02 00:00:00
258
+ partition pm values less than (MAXVALUE));` )
259
+ tk .MustExec ("insert into t_ts values('2024-11-30 00:00:00'), ('2024-12-01 00:00:00'), ('2024-12-02 00:00:00')" )
260
+ tk .MustQuery ("select * from t_ts where report_updated = '2024-12-01 00:00:00'" ).Check (testkit .Rows ("2024-12-01 00:00:00" ))
261
+ tk .MustQuery ("explain select * from t_ts where report_updated = 20241201" ).Check (testkit .Rows (
262
+ "TableReader_7 10.00 root partition:p2 data:Selection_6" ,
263
+ "└─Selection_6 10.00 cop[tikv] eq(test.t_ts.report_updated, 2024-12-01 00:00:00)" ,
264
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_ts keep order:false, stats:pseudo" ))
265
+ tk .MustQuery ("explain select * from t_ts where report_updated = '2024-12-01 00:00:00'" ).Check (testkit .Rows (
266
+ "TableReader_7 10.00 root partition:p2 data:Selection_6" ,
267
+ "└─Selection_6 10.00 cop[tikv] eq(test.t_ts.report_updated, 2024-12-01 00:00:00.000000)" ,
268
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_ts keep order:false, stats:pseudo" ))
269
+ rs := tk .MustQuery ("explain select * from t_ts where report_updated > unix_timestamp('2008-05-01 00:00:00')" ).Rows ()
270
+ require .Equal (t , rs [0 ][3 ], "partition:all" )
271
+ //MysQL explain:
272
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
273
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
274
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
275
+ //| 1 | SIMPLE | t_ts | p1,p2,pm | ALL | NULL | NULL | NULL | NULL | 3 | 33.33 | Using where |
276
+ //+----+-------------+-------+------------+------+---------------+------+---------+------+------+----------+-------------+
277
+
278
+ // case 3: hash partition
279
+ tk .MustExec (`CREATE TABLE t_hash(a int, b int) PARTITION BY HASH(a) PARTITIONS 6` )
280
+ tk .MustExec (`insert into t_hash values(1, 1), (10, 10), (26, 26)` )
281
+ tk .MustQuery (`select * from t_hash where a = '1'` ).Check (testkit .Rows ("1 1" ))
282
+ tk .MustQuery (`explain select * from t_hash where a = '1'` ).Check (testkit .Rows (
283
+ "TableReader_7 10.00 root partition:p1 data:Selection_6" ,
284
+ "└─Selection_6 10.00 cop[tikv] eq(test.t_hash.a, 1)" ,
285
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_hash keep order:false, stats:pseudo" ))
286
+ // MySQL explain:
287
+ //+----+-------------+--------+------------+------+---------------+------+---------+------+------+----------+-------------+
288
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
289
+ //+----+-------------+--------+------------+------+---------------+------+---------+------+------+----------+-------------+
290
+ //| 1 | SIMPLE | t_hash | p1 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
291
+ //+----+-------------+--------+------------+------+---------------+------+---------+------+------+----------+-------------+
292
+
293
+ // case 4: range columns partition
294
+ tk .MustExec (`CREATE TABLE t_range_col(a int, b int)
295
+ PARTITION BY RANGE COLUMNS(a) (
296
+ PARTITION p_100 VALUES LESS THAN (100),
297
+ PARTITION p_200 VALUES LESS THAN (200),
298
+ PARTITION p_300 VALUES LESS THAN (300),
299
+ PARTITION p_max VALUES LESS THAN MAXVALUE
300
+ );` )
301
+ tk .MustExec (`insert into t_range_col values(1, 1), (100, 100), (200, 200);` )
302
+ // 4.1.1 test between castIntAsReal(int) and real
303
+ tk .MustQuery (`select * from t_range_col where a between '100' and '199';` ).Check (testkit .Rows ("100 100" ))
304
+ tk .MustQuery (`explain select * from t_range_col where a between '100' and '199'` ).Check (testkit .Rows (
305
+ "TableReader_7 8000.00 root partition:p_200 data:Selection_6" ,
306
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t_range_col.a, double BINARY), 100), le(cast(test.t_range_col.a, double BINARY), 199)" ,
307
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_range_col keep order:false, stats:pseudo" ))
308
+ // MySQL explain:
309
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
310
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
311
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
312
+ //| 1 | SIMPLE | t_range_col | p_200 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
313
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
314
+
315
+ // 4.1.2 test between castIntAsReal(int) and real
316
+ tk .MustQuery (`select * from t_range_col where a between "ddd" and "199";` ).Sort ().Check (testkit .Rows ("1 1" , "100 100" ))
317
+ tk .MustQuery (`explain select * from t where a between "ddd" and "199";` ).Check (testkit .Rows (
318
+ "TableReader_7 8000.00 root partition:p1,p2 data:Selection_6" ,
319
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 0), le(cast(test.t.a, double BINARY), 199)" ,
320
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
321
+ // MySQL explain:
322
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
323
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
324
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
325
+ //| 1 | SIMPLE | t_range_col | p_100,p_200 | ALL | NULL | NULL | NULL | NULL | 2 | 50.00 | Using where |
326
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
327
+
328
+ // 4.1.3 test between castIntAsReal(int) and real
329
+ tk .MustQuery (`select * from t_range_col where a between "23.12" and "199.99";` ).Check (testkit .Rows ("100 100" ))
330
+ tk .MustQuery (`explain select * from t_range_col where a between "23.12" and "199.99";` ).Check (
331
+ testkit .Rows ("TableReader_7 8000.00 root partition:p_100,p_200 data:Selection_6" ,
332
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t_range_col.a, double BINARY), 23.12), le(cast(test.t_range_col.a, double BINARY), 199.99)" ,
333
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_range_col keep order:false, stats:pseudo" ))
334
+ // MySQL explain:
335
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
336
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
337
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
338
+ //| 1 | SIMPLE | t_range_col | p_100,p_200 | ALL | NULL | NULL | NULL | NULL | 2 | 50.00 | Using where |
339
+ //+----+-------------+-------------+-------------+------+---------------+------+---------+------+------+----------+-------------+
340
+
341
+ // 4.1.4 test between castIntAsReal(int) and real
342
+ tk .MustQuery (`select * from t_range_col where a between "23.12" and cast("199.99" as decimal);` ).Sort ().Check (testkit .Rows ("100 100" , "200 200" ))
343
+ tk .MustQuery (`explain select * from t where a between "23.12" and cast("199.99" as decimal);` ).Check (
344
+ testkit .Rows ("TableReader_7 8000.00 root partition:all data:Selection_6" ,
345
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t.a, double BINARY), 23.12), le(cast(test.t.a, double BINARY), 200)" ,
346
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t keep order:false, stats:pseudo" ))
347
+ // MySQL explain:
348
+ //+----+-------------+-------------+-------------------+------+---------------+------+---------+------+------+----------+-------------+
349
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
350
+ //+----+-------------+-------------+-------------------+------+---------------+------+---------+------+------+----------+-------------+
351
+ //| 1 | SIMPLE | t_range_col | p_100,p_200,p_300 | ALL | NULL | NULL | NULL | NULL | 3 | 33.33 | Using where |
352
+ //+----+-------------+-------------+-------------------+------+---------------+------+---------+------+------+----------+-------------+
353
+
354
+ // 4.2.1 test between castIntAsDecimal(int) and decimal
355
+ tk .MustQuery (`select * from t_range_col where a between 100.00 and 199.99;` ).Check (testkit .Rows ("100 100" ))
356
+ tk .MustQuery (`explain select * from t_range_col where a between 100.00 and 199.99` ).Check (testkit .Rows (
357
+ "TableReader_7 8000.00 root partition:p_200 data:Selection_6" ,
358
+ "└─Selection_6 8000.00 cop[tikv] ge(cast(test.t_range_col.a, decimal(10,0) BINARY), 100.00), le(cast(test.t_range_col.a, decimal(10,0) BINARY), 199.99)" ,
359
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_range_col keep order:false, stats:pseudo" ))
360
+ // MySQL explain:
361
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
362
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
363
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
364
+ //| 1 | SIMPLE | t_range_col | p_200 | ALL | NULL | NULL | NULL | NULL | 1 | 100.00 | Using where |
365
+ //+----+-------------+-------------+------------+------+---------------+------+---------+------+------+----------+-------------+
366
+
367
+ // case 5: test range column partition, and partition key is non-numeric type
368
+ tk .MustExec (`CREATE TABLE t_range_col_v2(a binary(1), b int)
369
+ PARTITION BY RANGE COLUMNS(a) (
370
+ PARTITION p_100 VALUES LESS THAN (_binary 0x03),
371
+ PARTITION p_200 VALUES LESS THAN (_binary 0xc0),
372
+ PARTITION p_300 VALUES LESS THAN (_binary 0xfe),
373
+ PARTITION p_max VALUES LESS THAN MAXVALUE
374
+ );` )
375
+ tk .MustExec (`insert into t_range_col_v2 values(0x01, 1), (0x03, 1), (0x09, 1), (0xc0, 1), (0xcc, 1), (0xfd, 1), (0xff, 1);` )
376
+ tk .MustQuery (`select * from t_range_col_v2 where a between 0x03 and 0xb0;` ).Sort ().Check (testkit .Rows (
377
+ "\u0003 1" ,
378
+ "\u0009 1" ))
379
+ tk .MustQuery (`explain select * from t_range_col_v2 where a between 0x03 and 0xb0;` ).Check (testkit .Rows (
380
+ "TableReader_7 250.00 root partition:p_200 data:Selection_6" ,
381
+ "└─Selection_6 250.00 cop[tikv] ge(test.t_range_col_v2.a, \" 0x03\" ), le(test.t_range_col_v2.a, \" 0xb0\" )" ,
382
+ " └─TableFullScan_5 10000.00 cop[tikv] table:t_range_col_v2 keep order:false, stats:pseudo" ))
383
+ // MySQL explain:
384
+ //+----+-------------+----------------+------------+------+---------------+------+---------+------+------+----------+-------------+
385
+ //| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
386
+ //+----+-------------+----------------+------------+------+---------------+------+---------+------+------+----------+-------------+
387
+ //| 1 | SIMPLE | t_range_col_v2 | p_200 | ALL | NULL | NULL | NULL | NULL | 2 | 50.00 | Using where |
388
+ //+----+-------------+----------------+------------+------+---------------+------+---------+------+------+----------+-------------+
389
+ }
390
+
178
391
func TestNotReadOnlySQLOnTiFlash (t * testing.T ) {
179
392
store := testkit .CreateMockStore (t )
180
393
tk := testkit .NewTestKit (t , store )
0 commit comments