From ee3d4ec4141a21ade09ae5ce7d26419abf480c4b Mon Sep 17 00:00:00 2001 From: Dave Gosselin Date: Wed, 31 Jan 2024 11:59:21 -0500 Subject: [PATCH] MDEV-12404 Index condition pushdown on partitioned tables Support index condition pushdown within partitioned tables. - ha_partition will pass the pushed index condition into all of the used partitions. - We require that all of the partitions to handle the pushed index condition in the same way. - When using ICP, one may read rows (e.g. call h->index_read_map(buf, ...) only to buf= table->record[0], for two reasons: * Pushed index condition's Item_field objects point into record[0] * InnoDB requires this: it calls offset() which assumes record[0]. So, when using ICP, ha_partition will read partition records to table->record[0] and then will copy record away if it needs it to be elsewhere. --- mysql-test/main/ignored_index.result | 2 +- mysql-test/main/partition_icp.result | 160 ++++++++++++++++++ mysql-test/main/partition_icp.test | 117 +++++++++++++ mysql-test/main/partition_mrr_aria.result | 4 +- mysql-test/main/partition_mrr_innodb.result | 4 +- mysql-test/main/partition_mrr_myisam.result | 6 +- mysql-test/main/partition_pruning.result | 30 ++-- sql/ha_partition.cc | 114 ++++++++++++- sql/ha_partition.h | 6 +- storage/example/ha_example.cc | 2 - .../rocksdb/r/rocksdb_cf_per_partition.result | 4 +- 11 files changed, 411 insertions(+), 38 deletions(-) create mode 100644 mysql-test/main/partition_icp.result create mode 100644 mysql-test/main/partition_icp.test diff --git a/mysql-test/main/ignored_index.result b/mysql-test/main/ignored_index.result index 176ca61decdf2..21c7cfea0bcd3 100644 --- a/mysql-test/main/ignored_index.result +++ b/mysql-test/main/ignored_index.result @@ -371,7 +371,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t1 index NULL a 2 NULL 14 Using index EXPLAIN SELECT * FROM t1 WHERE a = '04'; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t1 ref a a 2 const 2 Using where +1 SIMPLE t1 ref a a 2 const 2 Using index condition ALTER TABLE t1 ALTER INDEX b IGNORED; EXPLAIN SELECT b FROM t1; id select_type table type possible_keys key key_len ref rows Extra diff --git a/mysql-test/main/partition_icp.result b/mysql-test/main/partition_icp.result new file mode 100644 index 0000000000000..c7aa2cb63e9d8 --- /dev/null +++ b/mysql-test/main/partition_icp.result @@ -0,0 +1,160 @@ +set @old_handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @old_handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +CREATE TABLE t1 (a int PRIMARY KEY, b BLOB, c varchar(16) DEFAULT 'Filler...', +INDEX (b(4), a)) ENGINE = MyISAM PARTITION BY HASH (a) PARTITIONS 3; +INSERT INTO t1 (a, b) VALUES (1, 0xdeadbeef), (2, "text filler"), +(3, 'filler...'), (4, " more filler "), (5, "test text"), (6, "testing..."); +SELECT a, HEX(b) FROM t1 WHERE b >= 'te' and (a % 2); +a HEX(b) +5 746573742074657874 +1 DEADBEEF +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +@old_handler_icp_attempts = @handler_icp_attempts +1 +select @old_handler_icp_match = @handler_icp_match; +@old_handler_icp_match = @handler_icp_match +1 +CREATE TABLE t2 (a int PRIMARY KEY, b BLOB, c varchar(16) DEFAULT 'Filler...', +INDEX (b(4), a)) ENGINE = innodb PARTITION BY HASH (a) PARTITIONS 3; +INSERT INTO t2 (a, b) VALUES (1, 0xdeadbeef), (2, "text filler"), +(3, 'filler...'), (4, " more filler "), (5, "test text"), (6, "testing..."); +set @@optimizer_switch='index_condition_pushdown=off'; +SELECT a, HEX(b) FROM t2 WHERE b >= 'te' and (a % 2); +a HEX(b) +5 746573742074657874 +1 DEADBEEF +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +@old_handler_icp_attempts = @handler_icp_attempts +1 +select @old_handler_icp_match = @handler_icp_match; +@old_handler_icp_match = @handler_icp_match +1 +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT a, HEX(b) FROM t2 WHERE b >= 'te' and (a % 2); +a HEX(b) +5 746573742074657874 +1 DEADBEEF +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +@old_handler_icp_attempts < @handler_icp_attempts +1 +select @old_handler_icp_match < @handler_icp_match; +@old_handler_icp_match < @handler_icp_match +1 +CREATE TABLE t3 ( +pk INT PRIMARY KEY, +a INT, +b INT, +c INT, +filler varchar(100), +key(a,b,c) +) engine=innodb partition by hash(pk) partitions 4; +INSERT INTO t3 SELECT seq, seq, seq, seq, 'hello' FROM seq_1_to_10000; +set @@optimizer_switch='index_condition_pushdown=off'; +set @old_handler_icp_attempts = @handler_icp_attempts; +set @old_handler_icp_match = @handler_icp_match; +SELECT * from t3 where a < 10 AND (b+1>3); +pk a b c filler +3 3 3 3 hello +4 4 4 4 hello +5 5 5 5 hello +6 6 6 6 hello +7 7 7 7 hello +8 8 8 8 hello +9 9 9 9 hello +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +@old_handler_icp_attempts = @handler_icp_attempts +1 +select @old_handler_icp_match = @handler_icp_match; +@old_handler_icp_match = @handler_icp_match +1 +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT * from t3 where a < 10 AND (b+1>3); +pk a b c filler +3 3 3 3 hello +4 4 4 4 hello +5 5 5 5 hello +6 6 6 6 hello +7 7 7 7 hello +8 8 8 8 hello +9 9 9 9 hello +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +@old_handler_icp_attempts < @handler_icp_attempts +1 +select @old_handler_icp_match < @handler_icp_match; +@old_handler_icp_match < @handler_icp_match +1 +CREATE TABLE t4 ( +pk INT PRIMARY KEY, +a INT, +b INT, +c INT, +filler varchar(100), +key(a,b,c) +) engine=myisam partition by hash(pk) partitions 4; +INSERT INTO t4 SELECT seq, seq, seq, seq, 'hello' FROM seq_1_to_10000; +set @@optimizer_switch='index_condition_pushdown=off'; +set @old_handler_icp_attempts = @handler_icp_attempts; +set @old_handler_icp_match = @handler_icp_match; +SELECT * from t4 where a < 10 AND (b+1>3); +pk a b c filler +3 3 3 3 hello +4 4 4 4 hello +5 5 5 5 hello +6 6 6 6 hello +7 7 7 7 hello +8 8 8 8 hello +9 9 9 9 hello +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +@old_handler_icp_attempts = @handler_icp_attempts +1 +select @old_handler_icp_match = @handler_icp_match; +@old_handler_icp_match = @handler_icp_match +1 +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT * from t4 where a < 10 AND (b+1>3); +pk a b c filler +3 3 3 3 hello +4 4 4 4 hello +5 5 5 5 hello +6 6 6 6 hello +7 7 7 7 hello +8 8 8 8 hello +9 9 9 9 hello +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +@old_handler_icp_attempts < @handler_icp_attempts +1 +select @old_handler_icp_match < @handler_icp_match; +@old_handler_icp_match < @handler_icp_match +1 +create table t5(pk int primary key, kp1 int, kp2 int, filler int, key(kp1, kp2)) partition by hash(pk) partitions 2; +insert into t5 select seq, seq/40, seq, seq from seq_1_to_4000; +select * from t5 where t5.kp1=10 and mod(t5.kp2,2)=1 and t5.kp2+1<401; +pk kp1 kp2 filler +381 10 381 381 +383 10 383 383 +385 10 385 385 +387 10 387 387 +389 10 389 389 +391 10 391 391 +393 10 393 393 +395 10 395 395 +397 10 397 397 +399 10 399 399 +drop table t1, t2, t3, t4, t5; +# +# End of 11.4 tests +# diff --git a/mysql-test/main/partition_icp.test b/mysql-test/main/partition_icp.test new file mode 100644 index 0000000000000..38308590b5685 --- /dev/null +++ b/mysql-test/main/partition_icp.test @@ -0,0 +1,117 @@ +# +# MDEV-12404 Test Index Condition Pushdown for Partitioned Tables +# + +--source include/have_partition.inc +--source include/have_innodb.inc +--source include/have_sequence.inc + +# Get current values of handler_icp_attempts and handler_icp_match as integers which we'll use to compare against later. +set @old_handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @old_handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); + +# BLOBs are rejected by MyISAM +CREATE TABLE t1 (a int PRIMARY KEY, b BLOB, c varchar(16) DEFAULT 'Filler...', +INDEX (b(4), a)) ENGINE = MyISAM PARTITION BY HASH (a) PARTITIONS 3; + +INSERT INTO t1 (a, b) VALUES (1, 0xdeadbeef), (2, "text filler"), +(3, 'filler...'), (4, " more filler "), (5, "test text"), (6, "testing..."); + +SELECT a, HEX(b) FROM t1 WHERE b >= 'te' and (a % 2); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); + +# Verify that ICP was not invoked for isam (unsupported) by verifying that handler_icp_attempts and handler_icp_match are unchanged. +select @old_handler_icp_attempts = @handler_icp_attempts; +select @old_handler_icp_match = @handler_icp_match; + +# BLOBs allowed by InnoDB +CREATE TABLE t2 (a int PRIMARY KEY, b BLOB, c varchar(16) DEFAULT 'Filler...', +INDEX (b(4), a)) ENGINE = innodb PARTITION BY HASH (a) PARTITIONS 3; + +INSERT INTO t2 (a, b) VALUES (1, 0xdeadbeef), (2, "text filler"), +(3, 'filler...'), (4, " more filler "), (5, "test text"), (6, "testing..."); + +# Disable ICP and verify that ICP was not invoked by showing that handler_icp_attempts and handler_icp_match are unchanged. +set @@optimizer_switch='index_condition_pushdown=off'; +SELECT a, HEX(b) FROM t2 WHERE b >= 'te' and (a % 2); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +select @old_handler_icp_match = @handler_icp_match; + +# Enable index condition pushdown then verify that the pushed condition was checked. +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT a, HEX(b) FROM t2 WHERE b >= 'te' and (a % 2); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +select @old_handler_icp_match < @handler_icp_match; + +CREATE TABLE t3 ( + pk INT PRIMARY KEY, + a INT, + b INT, + c INT, + filler varchar(100), + key(a,b,c) + ) engine=innodb partition by hash(pk) partitions 4; + +INSERT INTO t3 SELECT seq, seq, seq, seq, 'hello' FROM seq_1_to_10000; + +# Disable ICP and verify that ICP was not invoked by verifying that handler_icp_attempts and handler_icp_match are unchanged. +set @@optimizer_switch='index_condition_pushdown=off'; +set @old_handler_icp_attempts = @handler_icp_attempts; +set @old_handler_icp_match = @handler_icp_match; +SELECT * from t3 where a < 10 AND (b+1>3); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +select @old_handler_icp_match = @handler_icp_match; + +# Enable index condition pushdown then verify that the pushed condition was checked. +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT * from t3 where a < 10 AND (b+1>3); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +select @old_handler_icp_match < @handler_icp_match; + +CREATE TABLE t4 ( + pk INT PRIMARY KEY, + a INT, + b INT, + c INT, + filler varchar(100), + key(a,b,c) + ) engine=myisam partition by hash(pk) partitions 4; + +INSERT INTO t4 SELECT seq, seq, seq, seq, 'hello' FROM seq_1_to_10000; + +# Disable ICP and verify that ICP was not invoked by verifying that handler_icp_attempts and handler_icp_match are unchanged. +set @@optimizer_switch='index_condition_pushdown=off'; +set @old_handler_icp_attempts = @handler_icp_attempts; +set @old_handler_icp_match = @handler_icp_match; +SELECT * from t4 where a < 10 AND (b+1>3); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts = @handler_icp_attempts; +select @old_handler_icp_match = @handler_icp_match; + +# Enable index condition pushdown, then verify that the pushed condition was checked. +set @@optimizer_switch='index_condition_pushdown=on'; +SELECT * from t4 where a < 10 AND (b+1>3); +set @handler_icp_attempts=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_attempts'); +set @handler_icp_match=(select cast(variable_value as int) from information_schema.session_status where variable_name='handler_icp_match'); +select @old_handler_icp_attempts < @handler_icp_attempts; +select @old_handler_icp_match < @handler_icp_match; + +create table t5(pk int primary key, kp1 int, kp2 int, filler int, key(kp1, kp2)) partition by hash(pk) partitions 2; +insert into t5 select seq, seq/40, seq, seq from seq_1_to_4000; +select * from t5 where t5.kp1=10 and mod(t5.kp2,2)=1 and t5.kp2+1<401; + +drop table t1, t2, t3, t4, t5; + +--echo # +--echo # End of 11.4 tests +--echo # diff --git a/mysql-test/main/partition_mrr_aria.result b/mysql-test/main/partition_mrr_aria.result index c798300728178..9ca5bed7a88d9 100644 --- a/mysql-test/main/partition_mrr_aria.result +++ b/mysql-test/main/partition_mrr_aria.result @@ -44,7 +44,7 @@ set optimizer_switch='mrr=on'; explain select * from t3 force index (key_col) where key_col < 3; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t3 range key_col key_col 5 NULL # Using where; Rowid-ordered scan +1 SIMPLE t3 range key_col key_col 5 NULL # Using index condition; Rowid-ordered scan select * from t3 force index (key_col) where key_col < 3; ID part_id key_col col2 1 0 0 123456 @@ -190,7 +190,7 @@ tp a b c a explain extended select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t2 range idx idx 5 NULL 2 100.00 Using where; Using index -1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition(BKA); Using join buffer (flat, BKA join); Rowid-ordered scan +1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan Warnings: Note 1003 select `test`.`t1`.`tp` AS `tp`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t2`.`a` AS `a` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t2`.`a` in (3,4) and `test`.`t1`.`b` / 10 = 4 select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; diff --git a/mysql-test/main/partition_mrr_innodb.result b/mysql-test/main/partition_mrr_innodb.result index 7d91fafef7c6a..690aaaf28f0d6 100644 --- a/mysql-test/main/partition_mrr_innodb.result +++ b/mysql-test/main/partition_mrr_innodb.result @@ -44,7 +44,7 @@ set optimizer_switch='mrr=on'; explain select * from t3 force index (key_col) where key_col < 3; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t3 range key_col key_col 5 NULL # Using where; Rowid-ordered scan +1 SIMPLE t3 range key_col key_col 5 NULL # Using index condition; Rowid-ordered scan select * from t3 force index (key_col) where key_col < 3; ID part_id key_col col2 1 0 0 123456 @@ -190,7 +190,7 @@ tp a b c a explain extended select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t2 range idx idx 5 NULL 2 100.00 Using where; Using index -1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition(BKA); Using join buffer (flat, BKA join); Rowid-ordered scan +1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan Warnings: Note 1003 select `test`.`t1`.`tp` AS `tp`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t2`.`a` AS `a` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t2`.`a` in (3,4) and `test`.`t1`.`b` / 10 = 4 select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; diff --git a/mysql-test/main/partition_mrr_myisam.result b/mysql-test/main/partition_mrr_myisam.result index 9155851a60a88..f4df89f72be8b 100644 --- a/mysql-test/main/partition_mrr_myisam.result +++ b/mysql-test/main/partition_mrr_myisam.result @@ -44,7 +44,7 @@ set optimizer_switch='mrr=on'; explain select * from t3 force index (key_col) where key_col < 3; id select_type table type possible_keys key key_len ref rows Extra -1 SIMPLE t3 range key_col key_col 5 NULL # Using where; Rowid-ordered scan +1 SIMPLE t3 range key_col key_col 5 NULL # Using index condition; Rowid-ordered scan select * from t3 force index (key_col) where key_col < 3; ID part_id key_col col2 1 0 0 123456 @@ -190,7 +190,7 @@ tp a b c a explain extended select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t2 range idx idx 5 NULL 2 100.00 Using where; Using index -1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition(BKA); Using join buffer (flat, BKA join); Rowid-ordered scan +1 SIMPLE t1 ref idx idx 5 test.t2.a 12 100.00 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan Warnings: Note 1003 select `test`.`t1`.`tp` AS `tp`,`test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t1`.`c` AS `c`,`test`.`t2`.`a` AS `a` from `test`.`t1` join `test`.`t2` where `test`.`t1`.`a` = `test`.`t2`.`a` and `test`.`t2`.`a` in (3,4) and `test`.`t1`.`b` / 10 = 4 select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; @@ -294,6 +294,6 @@ explain select * from t1,t2 where t2.a in (3,4) and t1.a=t2.a and (t1.b / 10) = 4; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE t2 range idx idx 5 NULL 2 Using where; Using index -1 SIMPLE t1 ref idx idx 5 test.t2.a 12 Using index condition(BKA); Using join buffer (flat, BKA join); Rowid-ordered scan +1 SIMPLE t1 ref idx idx 5 test.t2.a 12 Using index condition; Using join buffer (flat, BKA join); Rowid-ordered scan set join_cache_level=@tmp1, optimizer_switch=@tmp2; drop table t0,t1,t2; diff --git a/mysql-test/main/partition_pruning.result b/mysql-test/main/partition_pruning.result index 5461011d5b2d4..81c2681c34d61 100644 --- a/mysql-test/main/partition_pruning.result +++ b/mysql-test/main/partition_pruning.result @@ -2676,12 +2676,12 @@ explain partitions select * from t1 X, t1 Y where X.b = Y.b and (X.a=1 or X.a=2) and (Y.a=2 or Y.a=3); id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE X p1,p2 range a,b a 4 NULL 4 Using where +1 SIMPLE X p1,p2 range a,b a 4 NULL 4 Using index condition 1 SIMPLE Y p2,p3 ref a,b b 4 test.X.b 1 Using where explain partitions select * from t1 X, t1 Y where X.a = Y.a and (X.a=1 or X.a=2); id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE X p1,p2 range a a 4 NULL 4 Using where +1 SIMPLE X p1,p2 range a a 4 NULL 4 Using index condition 1 SIMPLE Y p1,p2 ref a a 4 test.X.a 1 drop table t1; create table t1 (a int) partition by hash(a) partitions 20; @@ -2920,12 +2920,12 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t2 p0,p1,p2,p3,p4 ALL b NULL NULL NULL 910 Using where explain extended select * from t2 where b > 5 and b < 7; id select_type table type possible_keys key key_len ref rows filtered Extra -1 SIMPLE t2 range b b 5 NULL 77 100.00 Using where +1 SIMPLE t2 range b b 5 NULL 77 100.00 Using index condition Warnings: Note 1003 select `test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t2` where `test`.`t2`.`b` > 5 and `test`.`t2`.`b` < 7 explain partitions select * from t2 where b > 5 and b < 7; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 77 Using where +1 SIMPLE t2 p0,p1,p2,p3,p4 range b b 5 NULL 77 Using index condition explain extended select * from t2 where b > 0 and b < 5; id select_type table type possible_keys key key_len ref rows filtered Extra 1 SIMPLE t2 ALL b NULL NULL NULL 910 41.87 Using where @@ -3372,46 +3372,46 @@ id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 <= 1; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1 range PRIMARY PRIMARY 8 NULL 1 Using where +1 SIMPLE t1 p1 range PRIMARY PRIMARY 8 NULL 1 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 = 1; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p1 const PRIMARY PRIMARY 8 const,const 1 EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 >= 1; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 > 1; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 < 3; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1 range PRIMARY PRIMARY 8 NULL 2 Using where +1 SIMPLE t1 p1 range PRIMARY PRIMARY 8 NULL 2 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 1 AND c2 <= 3; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 <= 3; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 = 3; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p2 const PRIMARY PRIMARY 8 const,const 1 EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 >= 3; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 2 Using where +1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 2 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 > 3; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 1 Using where +1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 1 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 < 4; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 2 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 <= 4; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using where +1 SIMPLE t1 p1,p2 range PRIMARY PRIMARY 8 NULL 3 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 = 4; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE t1 p2 const PRIMARY PRIMARY 8 const,const 1 EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 >= 4; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 1 Using where +1 SIMPLE t1 p2 range PRIMARY PRIMARY 8 NULL 1 Using index condition EXPLAIN PARTITIONS SELECT * FROM t1 WHERE c1 = 2 AND c2 > 4; id select_type table partitions type possible_keys key key_len ref rows Extra 1 SIMPLE NULL NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables diff --git a/sql/ha_partition.cc b/sql/ha_partition.cc index f7b84ff3be801..1fbeb71b6412c 100644 --- a/sql/ha_partition.cc +++ b/sql/ha_partition.cc @@ -62,6 +62,7 @@ #include "ddl_log.h" #include "debug_sync.h" +#include /* First 4 bytes in the .par file is the number of 32-bit words in the file */ #define PAR_WORD_SIZE 4 @@ -82,6 +83,30 @@ static const char *ha_par_ext= PAR_EXT; +/* + Index Condition Pushdown relies on invoking val_int() on the pushed index + condition to see if the condition applies to the current row. For that + to work we need to ensure that table->record[0] is populated correctly + because Item instances rely on table->record[0] for item evaluation. Doing + so would complicate the calling code, so instead encapsulate that behind + this function to juggle between buffers like m_ordered_rec_buffer, etc and + table->record[0] during index condition evaluation (if present). +*/ +using IndexOperationFunc= std::function; +static int read_with_icp(TABLE* table, + bool has_idx_cond, + uchar* record_buf, + size_t record_buf_len, + IndexOperationFunc func) +{ + if (!has_idx_cond) + return func(record_buf); + + int error= func(table->record[0]); + memcpy(record_buf, table->record[0], record_buf_len); + return error; +} + /**************************************************************************** MODULE create/delete handler object ****************************************************************************/ @@ -7941,10 +7966,17 @@ int ha_partition::handle_ordered_index_scan(uchar *buf, bool reverse_order) switch (m_index_scan_type) { case partition_index_read: - error= file->ha_index_read_map(rec_buf_ptr, - m_start_key.key, - m_start_key.keypart_map, - m_start_key.flag); + error= + read_with_icp(table, + pushed_idx_cond != nullptr, + rec_buf_ptr, + m_rec_length, + [this, file] (uchar* read_buf) { + return file->ha_index_read_map(read_buf, + m_start_key.key, + m_start_key.keypart_map, + m_start_key.flag); + }); /* Caller has specified reverse_order */ break; case partition_index_first: @@ -8399,10 +8431,27 @@ int ha_partition::handle_ordered_next(uchar *buf, bool is_next_same) } } else if (!is_next_same) - error= file->ha_index_next(rec_buf); + { + error= read_with_icp(table, + pushed_idx_cond != nullptr, + rec_buf, + m_rec_length, + [file] (uchar* read_buf) { + return file->ha_index_next(read_buf); + }); + } else - error= file->ha_index_next_same(rec_buf, m_start_key.key, - m_start_key.length); + { + error= read_with_icp(table, + pushed_idx_cond != nullptr, + rec_buf, + m_rec_length, + [this, file] (uchar* read_buf) { + return file->ha_index_next_same(read_buf, + m_start_key.key, + m_start_key.length); + }); + } if (unlikely(error)) { @@ -12227,6 +12276,57 @@ int ha_partition::info_push(uint info_type, void *info) DBUG_RETURN(error); } +static void cancel_pushed_idx_cond_impl(handler** m_file, + MY_BITMAP* read_partitions, + uint limit) +{ + for (uint i= bitmap_get_first_set(read_partitions); + i < limit; + i= bitmap_get_next_set(read_partitions, i)) + { + m_file[i]->cancel_pushed_idx_cond(); + } +} + +Item* ha_partition::idx_cond_push(uint keyno, Item* idx_cond) +{ + DBUG_ASSERT(pushed_idx_cond == nullptr); + DBUG_ASSERT(pushed_idx_cond_keyno == MAX_KEY); + + for (uint i= bitmap_get_first_set(&m_part_info->read_partitions); + i < m_tot_parts; + i= bitmap_get_next_set(&m_part_info->read_partitions, i)) + { + Item* res= m_file[i]->idx_cond_push(keyno, idx_cond); + if (!res) // Returning nullptr indicates success. + continue; + + // One of the partitions couldn't accept the pushed condition, or + // one of the partitions returned a partial pushed condition that + // indicates that it could handle some portion of the pushed index + // condition. At this point, we require all partitions to handle + // the pushed condition in the same way; consequently we need to + // cancel the pushed condition for the partitions that succeeded + // up to this point. + DBUG_ASSERT(i == bitmap_get_first_set(&m_part_info->read_partitions)); + DBUG_ASSERT(res == idx_cond); + if (res != idx_cond) + m_file[i]->cancel_pushed_idx_cond(); + cancel_pushed_idx_cond_impl(m_file, &m_part_info->read_partitions, i); + return idx_cond; + } + pushed_idx_cond= idx_cond; + pushed_idx_cond_keyno= keyno; + in_range_check_pushed_down = TRUE; + return NULL; +} + +void ha_partition::cancel_pushed_idx_cond() +{ + cancel_pushed_idx_cond_impl(m_file, &m_part_info->read_partitions, + m_tot_parts); + handler::cancel_pushed_idx_cond(); +} bool ha_partition::can_convert_nocopy(const Field &field, diff --git a/sql/ha_partition.h b/sql/ha_partition.h index d450f96f4f9d6..f5330e883b7a7 100644 --- a/sql/ha_partition.h +++ b/sql/ha_partition.h @@ -1309,10 +1309,6 @@ class ha_partition final :public handler The underlying storage engine might support Rowid Filtering. But ha_partition does not forward the needed SE API calls, so the feature will not be used. - - Note: It's the same with IndexConditionPushdown, except for its variant - of IndexConditionPushdown+BatchedKeyAccess (that one works). Because of - that, we do not clear HA_DO_INDEX_COND_PUSHDOWN here. */ return part_flags & ~HA_DO_RANGE_FILTER_PUSHDOWN; } @@ -1550,6 +1546,8 @@ class ha_partition final :public handler const COND *cond_push(const COND *cond) override; void cond_pop() override; int info_push(uint info_type, void *info) override; + Item *idx_cond_push(uint keyno, Item* idx_cond) override; + void cancel_pushed_idx_cond() override; private: int handle_opt_partitions(THD *thd, HA_CHECK_OPT *check_opt, uint flags); diff --git a/storage/example/ha_example.cc b/storage/example/ha_example.cc index fbad065760f77..874f03aff9c00 100644 --- a/storage/example/ha_example.cc +++ b/storage/example/ha_example.cc @@ -380,8 +380,6 @@ int ha_example::close(void) @endcode See ha_tina.cc for an example of extracting all of the data as strings. - ha_berekly.cc has an example of how to store it intact by "packing" it - for ha_berkeley's own native storage type. See the note for update_row() on auto_increments and timestamps. This case also applies to write_row(). diff --git a/storage/rocksdb/mysql-test/rocksdb/r/rocksdb_cf_per_partition.result b/storage/rocksdb/mysql-test/rocksdb/r/rocksdb_cf_per_partition.result index 32bb70a7464eb..b7ee3b952c10e 100644 --- a/storage/rocksdb/mysql-test/rocksdb/r/rocksdb_cf_per_partition.result +++ b/storage/rocksdb/mysql-test/rocksdb/r/rocksdb_cf_per_partition.result @@ -342,7 +342,7 @@ INSERT INTO t2 VALUES (400, 0x89ABC, 0x4, 1, 0x5); INSERT INTO t2 VALUES (500, 0x6789A, 0x5, 1, 0x7); EXPLAIN PARTITIONS SELECT * FROM t2 WHERE col2 = 0x6789A AND col4 = 1; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t2 custom_p5 ref col2 col2 74 const,const 1 Using where +1 SIMPLE t2 custom_p5 ref col2 col2 74 const,const 1 Using index condition ALTER TABLE t2 DROP KEY `col2`; ALTER TABLE t2 ADD KEY (`col3`, `col4`) COMMENT 'custom_p5_cfname=another_cf_for_p5'; SELECT DISTINCT(cf_name) FROM information_schema.rocksdb_cfstats WHERE cf_name='another_cf_for_p5'; @@ -355,7 +355,7 @@ test.t2 analyze Warning Engine-independent statistics are not collected for colu test.t2 analyze status OK EXPLAIN PARTITIONS SELECT * FROM t2 WHERE col3 = 0x4 AND col2 = 0x34567; id select_type table partitions type possible_keys key key_len ref rows Extra -1 SIMPLE t2 custom_p2 ref col3 col3 258 const # Using where +1 SIMPLE t2 custom_p2 ref col3 col3 258 const # Using index condition DROP TABLE t2; CREATE TABLE `t2` ( `col1` bigint(20) NOT NULL,