Skip to content

Commit

Permalink
MDEV-12404 Index condition pushdown on partitioned tables
Browse files Browse the repository at this point in the history
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.
  • Loading branch information
DaveGosselin-MariaDB committed Apr 17, 2024
1 parent e0b6db2 commit ee3d4ec
Show file tree
Hide file tree
Showing 11 changed files with 411 additions and 38 deletions.
2 changes: 1 addition & 1 deletion mysql-test/main/ignored_index.result
Expand Up @@ -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
Expand Down
160 changes: 160 additions & 0 deletions 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
#
117 changes: 117 additions & 0 deletions 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 #
4 changes: 2 additions & 2 deletions mysql-test/main/partition_mrr_aria.result
Expand Up @@ -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
Expand Down Expand Up @@ -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;
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/main/partition_mrr_innodb.result
Expand Up @@ -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
Expand Down Expand Up @@ -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;
Expand Down
6 changes: 3 additions & 3 deletions mysql-test/main/partition_mrr_myisam.result
Expand Up @@ -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
Expand Down Expand Up @@ -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;
Expand Down Expand Up @@ -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;

0 comments on commit ee3d4ec

Please sign in to comment.