From c73985f2ce8a391582787f3e310a011c1a712bec Mon Sep 17 00:00:00 2001 From: Andrei Date: Sat, 28 Jan 2023 14:30:46 +0200 Subject: [PATCH 1/3] MDEV-30010 post-push: fixing test results. --- ...nlog_recovery_after_checksum_change.result | 8 --- .../r/innodb_rc_insert_before_delete.result | 52 +++++++++++++++++++ 2 files changed, 52 insertions(+), 8 deletions(-) delete mode 100644 mysql-test/suite/binlog/r/binlog_recovery_after_checksum_change.result create mode 100644 mysql-test/suite/binlog/r/innodb_rc_insert_before_delete.result diff --git a/mysql-test/suite/binlog/r/binlog_recovery_after_checksum_change.result b/mysql-test/suite/binlog/r/binlog_recovery_after_checksum_change.result deleted file mode 100644 index 85b0b84c684..00000000000 --- a/mysql-test/suite/binlog/r/binlog_recovery_after_checksum_change.result +++ /dev/null @@ -1,8 +0,0 @@ -connection default; -set @@global.binlog_checksum=none; -set @@session.debug_dbug='d,crash_before_write_second_checkpoint_event'; -set @@global.binlog_checksum=crc32; -ERROR HY000: Lost connection to MySQL server during query -connection default; -NOT FOUND /Replication event checksum verification failed/ in mysqld.1.err -End of the tests diff --git a/mysql-test/suite/binlog/r/innodb_rc_insert_before_delete.result b/mysql-test/suite/binlog/r/innodb_rc_insert_before_delete.result new file mode 100644 index 00000000000..24d748b7673 --- /dev/null +++ b/mysql-test/suite/binlog/r/innodb_rc_insert_before_delete.result @@ -0,0 +1,52 @@ +connect pause_purge,localhost,root; +START TRANSACTION WITH CONSISTENT SNAPSHOT; +connection default; +CREATE TABLE t (pk int PRIMARY KEY, sk INT UNIQUE) ENGINE=InnoDB; +INSERT INTO t VALUES (10, 100); +connect con1,localhost,root; +BEGIN; +SELECT * FROM t WHERE sk = 100 FOR UPDATE; +pk sk +10 100 +connect con2,localhost,root; +SET DEBUG_SYNC="lock_wait_suspend_thread_enter SIGNAL insert_wait_started"; +INSERT INTO t VALUES (5, 100) # trx 1; +connect con3,localhost,root; +SET TRANSACTION ISOLATION LEVEL READ COMMITTED; +SET DEBUG_SYNC="now WAIT_FOR insert_wait_started"; +SET DEBUG_SYNC="lock_wait_suspend_thread_enter SIGNAL delete_started_waiting"; +BEGIN; +UPDATE t SET sk = 200 WHERE sk = 100; # trx 2; +connection con1; +SET DEBUG_SYNC="now WAIT_FOR delete_started_waiting"; +DELETE FROM t WHERE sk=100; +COMMIT; +disconnect con1; +connection con2; +disconnect con2; +connection con3; +must be logged in ROW format as the only event of trx 2 (con3) +INSERT INTO t VALUES (11, 101); +COMMIT; +include/show_binlog_events.inc +Log_name Pos Event_type Server_id End_log_pos Info +master-bin.000001 # Gtid # # BEGIN GTID #-#-# +master-bin.000001 # Query # # use `test`; DELETE FROM t WHERE sk=100 +master-bin.000001 # Xid # # COMMIT /* XID */ +master-bin.000001 # Gtid # # BEGIN GTID #-#-# +master-bin.000001 # Query # # use `test`; INSERT INTO t VALUES (5, 100) # trx 1 +master-bin.000001 # Xid # # COMMIT /* XID */ +master-bin.000001 # Gtid # # BEGIN GTID #-#-# +master-bin.000001 # Annotate_rows # # INSERT INTO t VALUES (11, 101) +master-bin.000001 # Table_map # # table_id: # (test.t) +master-bin.000001 # Write_rows_v1 # # table_id: # flags: STMT_END_F +master-bin.000001 # Xid # # COMMIT /* XID */ +disconnect con3; +connection default; +SELECT * FROM t; +pk sk +5 100 +11 101 +disconnect pause_purge; +SET DEBUG_SYNC="RESET"; +DROP TABLE t; From 9c6fcdb85ef0b82767a036764afafcc2483e906c Mon Sep 17 00:00:00 2001 From: Sergei Petrunia Date: Thu, 26 Jan 2023 12:04:28 +0300 Subject: [PATCH 2/3] MDEV-30218: Incorrect optimization for rowid_filtering, correction Enable use of Rowid Filter optimization with eq_ref access. Use the following assumptions: - Assume index-only access cost is 50% of non-index-only access cost. - Take into account that "Eq_ref access cache" reduces the number of lookups eq_ref access will make. = This means the number of Rowid Filter checks is reduced also = Eq_ref access cost is computed using that assumption (see prev_record_reads() call), so we should use it in all cost ' computations. --- mysql-test/main/rowid_filter.result | 58 +++++++++++++++++++++++++---- mysql-test/main/subselect2.result | 2 +- sql/sql_select.cc | 28 +++++++++++--- 3 files changed, 73 insertions(+), 15 deletions(-) diff --git a/mysql-test/main/rowid_filter.result b/mysql-test/main/rowid_filter.result index 2bfc5b1f20c..b35021b8513 100644 --- a/mysql-test/main/rowid_filter.result +++ b/mysql-test/main/rowid_filter.result @@ -336,7 +336,7 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND o_totalprice between 200000 and 230000; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 NULL 98 Using index condition -1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 Using where +1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (5%) Using where; Using rowid filter set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice FROM orders JOIN lineitem ON o_orderkey=l_orderkey WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND @@ -369,6 +369,14 @@ EXPLAIN "key_length": "4", "used_key_parts": ["o_orderkey"], "ref": ["dbt3_s001.lineitem.l_orderkey"], + "rowid_filter": { + "range": { + "key": "i_o_totalprice", + "used_key_parts": ["o_totalprice"] + }, + "rows": 69, + "selectivity_pct": 4.6 + }, "rows": 1, "filtered": 4.6, "attached_condition": "orders.o_totalprice between 200000 and 230000" @@ -381,7 +389,7 @@ WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND o_totalprice between 200000 and 230000; id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra 1 SIMPLE lineitem range PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity i_l_shipdate 4 NULL 98 98.00 100.00 100.00 Using index condition -1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 4.60 11.22 Using where +1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (5%) 0.11 (10%) 4.60 100.00 Using where; Using rowid filter set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, o_totalprice FROM orders JOIN lineitem ON o_orderkey=l_orderkey WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-01-31' AND @@ -420,12 +428,25 @@ ANALYZE "key_length": "4", "used_key_parts": ["o_orderkey"], "ref": ["dbt3_s001.lineitem.l_orderkey"], + "rowid_filter": { + "range": { + "key": "i_o_totalprice", + "used_key_parts": ["o_totalprice"] + }, + "rows": 69, + "selectivity_pct": 4.6, + "r_rows": 71, + "r_lookups": 96, + "r_selectivity_pct": 10.417, + "r_buffer_size": "REPLACED", + "r_filling_time_ms": "REPLACED" + }, "r_loops": 98, "rows": 1, - "r_rows": 1, + "r_rows": 0.1122, "r_total_time_ms": "REPLACED", "filtered": 4.6, - "r_filtered": 11.224, + "r_filtered": 100, "attached_condition": "orders.o_totalprice between 200000 and 230000" } } @@ -569,7 +590,7 @@ l_quantity > 45 AND o_totalprice between 180000 and 230000; id select_type table type possible_keys key key_len ref rows Extra 1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 509 (12%) Using index condition; Using where; Using rowid filter -1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 Using where +1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (9%) Using where; Using rowid filter set statement optimizer_switch='rowid_filter=on' for EXPLAIN FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice FROM orders JOIN lineitem ON o_orderkey=l_orderkey WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND @@ -613,6 +634,14 @@ EXPLAIN "key_length": "4", "used_key_parts": ["o_orderkey"], "ref": ["dbt3_s001.lineitem.l_orderkey"], + "rowid_filter": { + "range": { + "key": "i_o_totalprice", + "used_key_parts": ["o_totalprice"] + }, + "rows": 139, + "selectivity_pct": 9.2667 + }, "rows": 1, "filtered": 9.2667, "attached_condition": "orders.o_totalprice between 180000 and 230000" @@ -626,7 +655,7 @@ l_quantity > 45 AND o_totalprice between 180000 and 230000; id select_type table type possible_keys key key_len ref rows r_rows filtered r_filtered Extra 1 SIMPLE lineitem range|filter PRIMARY,i_l_shipdate,i_l_orderkey,i_l_orderkey_quantity,i_l_quantity i_l_shipdate|i_l_quantity 4|9 NULL 509 (12%) 60.00 (11%) 11.69 100.00 Using index condition; Using where; Using rowid filter -1 SIMPLE orders eq_ref PRIMARY,i_o_totalprice PRIMARY 4 dbt3_s001.lineitem.l_orderkey 1 1.00 9.27 26.67 Using where +1 SIMPLE orders eq_ref|filter PRIMARY,i_o_totalprice PRIMARY|i_o_totalprice 4|9 dbt3_s001.lineitem.l_orderkey 1 (9%) 0.27 (25%) 9.27 100.00 Using where; Using rowid filter set statement optimizer_switch='rowid_filter=on' for ANALYZE FORMAT=JSON SELECT o_orderkey, l_linenumber, l_shipdate, l_quantity, o_totalprice FROM orders JOIN lineitem ON o_orderkey=l_orderkey WHERE l_shipdate BETWEEN '1997-01-01' AND '1997-06-30' AND @@ -681,12 +710,25 @@ ANALYZE "key_length": "4", "used_key_parts": ["o_orderkey"], "ref": ["dbt3_s001.lineitem.l_orderkey"], + "rowid_filter": { + "range": { + "key": "i_o_totalprice", + "used_key_parts": ["o_totalprice"] + }, + "rows": 139, + "selectivity_pct": 9.2667, + "r_rows": 144, + "r_lookups": 59, + "r_selectivity_pct": 25.424, + "r_buffer_size": "REPLACED", + "r_filling_time_ms": "REPLACED" + }, "r_loops": 60, "rows": 1, - "r_rows": 1, + "r_rows": 0.2667, "r_total_time_ms": "REPLACED", "filtered": 9.2667, - "r_filtered": 26.667, + "r_filtered": 100, "attached_condition": "orders.o_totalprice between 180000 and 230000" } } diff --git a/mysql-test/main/subselect2.result b/mysql-test/main/subselect2.result index 55ac483157f..c54d635230f 100644 --- a/mysql-test/main/subselect2.result +++ b/mysql-test/main/subselect2.result @@ -132,7 +132,7 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY t3 eq_ref PRIMARY,FFOLDERID_IDX,CMFLDRPARNT_IDX PRIMARY 34 test.t3.PARENTID 1 Using where 1 PRIMARY t3 eq_ref PRIMARY,FFOLDERID_IDX,CMFLDRPARNT_IDX PRIMARY 34 test.t3.PARENTID 1 Using where 1 PRIMARY t3 eq_ref PRIMARY,FFOLDERID_IDX,CMFLDRPARNT_IDX PRIMARY 34 test.t3.PARENTID 1 Using where -1 PRIMARY t3 eq_ref PRIMARY,FFOLDERID_IDX,CMFLDRPARNT_IDX PRIMARY 34 test.t3.PARENTID 1 Using where +1 PRIMARY t3 ref|filter PRIMARY,FFOLDERID_IDX,CMFLDRPARNT_IDX FFOLDERID_IDX|CMFLDRPARNT_IDX 34|35 test.t3.PARENTID 1 (29%) Using where; Using rowid filter drop table t1, t2, t3, t4; CREATE TABLE t1 (a int(10) , PRIMARY KEY (a)) Engine=InnoDB; INSERT INTO t1 VALUES (1),(2); diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 333a9c1f50d..4ec7f5d746d 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -7902,7 +7902,27 @@ best_access_path(JOIN *join, (s->table->file->index_flags(start_key->key,0,1) & HA_DO_RANGE_FILTER_PUSHDOWN)) { - double rows= record_count * records; + double rows; + if (type == JT_EQ_REF) + { + /* + Treat EQ_REF access in a special way: + 1. We have no cost for index-only read. Assume its cost is 50% of + the cost of the full read. + + 2. A regular ref access will do #record_count lookups, but eq_ref + has "lookup cache" which reduces the number of lookups made. + The estimation code uses prev_record_reads() call to estimate: + + tmp = prev_record_reads(join_positions, idx, found_ref); + + Set the effective number of rows from "tmp" here. + */ + keyread_tmp= tmp/ 2; + rows= tmp; + } + else + rows= record_count * records; /* If we use filter F with selectivity s the the cost of fetching data @@ -7945,10 +7965,6 @@ best_access_path(JOIN *join, we cannot use filters as the cost calculation below would cause tmp to become negative. The future resultion is to not limit cost with worst_seek. - - We cannot use filter with JT_EQ_REF as in this case 'tmp' is - number of rows from prev_record_read() and keyread_tmp is 0. These - numbers are not usable with rowid filter code. */ double access_cost_factor= MY_MIN((rows - keyread_tmp) / rows, 1.0); if (!(records < s->worst_seeks && @@ -7956,7 +7972,7 @@ best_access_path(JOIN *join, trace_access_idx.add("rowid_filter_skipped", "worst/max seeks clipping"); else if (access_cost_factor <= 0.0) trace_access_idx.add("rowid_filter_skipped", "cost_factor <= 0"); - else if (type != JT_EQ_REF) + else { filter= table->best_range_rowid_filter_for_partial_join(start_key->key, From c8f2e9a5c0ac5905f28b050b7df5a9ffd914b7e7 Mon Sep 17 00:00:00 2001 From: Oleksandr Byelkin Date: Mon, 30 Jan 2023 11:49:42 +0100 Subject: [PATCH 3/3] Fix number of rows passing in case of EQ_REF --- sql/sql_select.cc | 8 +++++--- 1 file changed, 5 insertions(+), 3 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 4ec7f5d746d..0f8ead46ffc 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -7557,6 +7557,7 @@ best_access_path(JOIN *join, rec= MATCHING_ROWS_IN_OTHER_TABLE; // Fix for small tables Json_writer_object trace_access_idx(thd); + double eq_ref_rows= 0; /* full text keys require special treatment */ @@ -7595,7 +7596,8 @@ best_access_path(JOIN *join, type= JT_EQ_REF; trace_access_idx.add("access_type", join_type_str[type]) .add("index", keyinfo->name); - tmp = prev_record_reads(join_positions, idx, found_ref); + eq_ref_rows= tmp = prev_record_reads(join_positions, idx, + found_ref); records=1.0; } else @@ -7918,8 +7920,8 @@ best_access_path(JOIN *join, Set the effective number of rows from "tmp" here. */ - keyread_tmp= tmp/ 2; - rows= tmp; + keyread_tmp= COST_ADD(eq_ref_rows / 2, s->startup_cost); + rows= eq_ref_rows; } else rows= record_count * records;