mirror of
https://github.com/MariaDB/server.git
synced 2025-07-30 16:24:05 +03:00
MDEV-32837 long unique does not work like unique key when using replace
write_record() when performing REPLACE has an optimization: - if the unique violation happened in the last unique key, then do UPDATE - otherwise, do DELETE+INSERT This patch changes the way of detecting if this optimization can be applied if the table has long (hash based) unique (i.e. UNIQUE..USING HASH) constraints. Problem: The old condition did not take into account that TABLE_SHARE and TABLE see long uniques differently: - TABLE_SHARE sees as HA_KEY_ALG_LONG_HASH and HA_NOSAME - TABLE sees as usual non-unique indexes So the old condition could erroneously decide that the UPDATE optimization is possible when there are still some unique hash constraints in the table. Fix: - If the current key is a long unique, it now works as follows: UPDATE can be done if the current long unique is the last long unique, and there are no in-engine (normal) uniques. - For in-engine uniques nothing changes, it still works as before: If the current key is an in-engine (normal) unique: UPDATE can be done if it is the last normal unique.
This commit is contained in:
@ -660,5 +660,20 @@ Table Op Msg_type Msg_text
|
|||||||
test.t1 check status OK
|
test.t1 check status OK
|
||||||
drop table t1;
|
drop table t1;
|
||||||
#
|
#
|
||||||
|
# MDEV-32837 long unique does not work like unique key when using replace
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
a b c
|
||||||
|
2 2 2
|
||||||
|
3 1 1
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SELECT * FROM t1;
|
||||||
|
a b c
|
||||||
|
3 2 2
|
||||||
|
DROP TABLE t1;
|
||||||
|
#
|
||||||
# End of 10.5 tests
|
# End of 10.5 tests
|
||||||
#
|
#
|
||||||
|
@ -642,6 +642,19 @@ insert into t1 values (0);
|
|||||||
check table t1 extended;
|
check table t1 extended;
|
||||||
drop table t1;
|
drop table t1;
|
||||||
|
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # MDEV-32837 long unique does not work like unique key when using replace
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SELECT * FROM t1;
|
||||||
|
DROP TABLE t1;
|
||||||
|
|
||||||
--echo #
|
--echo #
|
||||||
--echo # End of 10.5 tests
|
--echo # End of 10.5 tests
|
||||||
--echo #
|
--echo #
|
||||||
|
95
mysql-test/main/long_unique_bugs_no_sp_protocol.result
Normal file
95
mysql-test/main/long_unique_bugs_no_sp_protocol.result
Normal file
@ -0,0 +1,95 @@
|
|||||||
|
#
|
||||||
|
# Start of 10.5 tests
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# MDEV-32837 long unique does not work like unique key when using replace
|
||||||
|
#
|
||||||
|
#
|
||||||
|
# Normal unique key + long unique key
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_delete 1
|
||||||
|
Handler_read_key 2
|
||||||
|
Handler_read_rnd 1
|
||||||
|
Handler_write 1
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
a b c
|
||||||
|
2 2 2
|
||||||
|
3 1 1
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_delete 1
|
||||||
|
Handler_read_key 3
|
||||||
|
Handler_read_rnd 2
|
||||||
|
Handler_update 1
|
||||||
|
Handler_write 1
|
||||||
|
SELECT * FROM t1;
|
||||||
|
a b c
|
||||||
|
3 2 2
|
||||||
|
DROP TABLE t1;
|
||||||
|
#
|
||||||
|
# Two long unique keys
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a INT, b INT, c INT, UNIQUE KEY a (a) USING HASH,UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_read_key 3
|
||||||
|
Handler_read_rnd 1
|
||||||
|
Handler_update 1
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
a b c
|
||||||
|
2 2 2
|
||||||
|
3 1 1
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_delete 1
|
||||||
|
Handler_read_key 4
|
||||||
|
Handler_read_rnd 2
|
||||||
|
Handler_update 1
|
||||||
|
SELECT * FROM t1;
|
||||||
|
a b c
|
||||||
|
3 2 2
|
||||||
|
DROP TABLE t1;
|
||||||
|
#
|
||||||
|
# One long unique key
|
||||||
|
#
|
||||||
|
CREATE TABLE t1 (a INT, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_read_key 1
|
||||||
|
Handler_read_rnd 1
|
||||||
|
Handler_update 1
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
a b c
|
||||||
|
2 2 2
|
||||||
|
3 1 1
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
Variable_name Value
|
||||||
|
Handler_read_key 1
|
||||||
|
Handler_read_rnd 1
|
||||||
|
Handler_update 1
|
||||||
|
SELECT * FROM t1;
|
||||||
|
a b c
|
||||||
|
3 1 1
|
||||||
|
3 2 2
|
||||||
|
DROP TABLE t1;
|
||||||
|
#
|
||||||
|
# End of 10.5 tests
|
||||||
|
#
|
68
mysql-test/main/long_unique_bugs_no_sp_protocol.test
Normal file
68
mysql-test/main/long_unique_bugs_no_sp_protocol.test
Normal file
@ -0,0 +1,68 @@
|
|||||||
|
if (`SELECT $SP_PROTOCOL > 0`)
|
||||||
|
{
|
||||||
|
--skip Test requires: sp-protocol disabled
|
||||||
|
}
|
||||||
|
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # Start of 10.5 tests
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # MDEV-32837 long unique does not work like unique key when using replace
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
# This test produces different Handler commands in the SHOW STATUS output
|
||||||
|
# with --sp-protocol. So it's here, in this *.test file with --sp-protocol disabled.
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # Normal unique key + long unique key
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
CREATE TABLE t1 (a INT PRIMARY KEY, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1;
|
||||||
|
DROP TABLE t1;
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # Two long unique keys
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
CREATE TABLE t1 (a INT, b INT, c INT, UNIQUE KEY a (a) USING HASH,UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1;
|
||||||
|
DROP TABLE t1;
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # One long unique key
|
||||||
|
--echo #
|
||||||
|
|
||||||
|
CREATE TABLE t1 (a INT, b INT, c INT, UNIQUE KEY `test` (b,c) USING HASH) ENGINE=MyISAM;
|
||||||
|
INSERT INTO t1 VALUES (1,1,1),(2,2,2);
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,1,1);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1 ORDER BY a;
|
||||||
|
FLUSH STATUS;
|
||||||
|
REPLACE INTO t1 VALUES (3,2,2);
|
||||||
|
SHOW STATUS WHERE Variable_name LIKE 'handler%' AND Value>0;
|
||||||
|
SELECT * FROM t1;
|
||||||
|
DROP TABLE t1;
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # End of 10.5 tests
|
||||||
|
--echo #
|
@ -1728,7 +1728,7 @@ int mysql_prepare_insert(THD *thd, TABLE_LIST *table_list,
|
|||||||
|
|
||||||
/* Check if there is more uniq keys after field */
|
/* Check if there is more uniq keys after field */
|
||||||
|
|
||||||
static int last_uniq_key(TABLE *table,uint keynr)
|
static int last_uniq_key(TABLE *table, const KEY *key, uint keynr)
|
||||||
{
|
{
|
||||||
/*
|
/*
|
||||||
When an underlying storage engine informs that the unique key
|
When an underlying storage engine informs that the unique key
|
||||||
@ -1748,7 +1748,7 @@ static int last_uniq_key(TABLE *table,uint keynr)
|
|||||||
return 0;
|
return 0;
|
||||||
|
|
||||||
while (++keynr < table->s->keys)
|
while (++keynr < table->s->keys)
|
||||||
if (table->key_info[keynr].flags & HA_NOSAME)
|
if (key[keynr].flags & HA_NOSAME)
|
||||||
return 0;
|
return 0;
|
||||||
return 1;
|
return 1;
|
||||||
}
|
}
|
||||||
@ -2064,8 +2064,27 @@ int write_record(THD *thd, TABLE *table, COPY_INFO *info, select_result *sink)
|
|||||||
tables which have ON UPDATE but have no ON DELETE triggers,
|
tables which have ON UPDATE but have no ON DELETE triggers,
|
||||||
we just should not expose this fact to users by invoking
|
we just should not expose this fact to users by invoking
|
||||||
ON UPDATE triggers.
|
ON UPDATE triggers.
|
||||||
|
|
||||||
|
Note, TABLE_SHARE and TABLE see long uniques differently:
|
||||||
|
- TABLE_SHARE sees as HA_KEY_ALG_LONG_HASH and HA_NOSAME
|
||||||
|
- TABLE sees as usual non-unique indexes
|
||||||
*/
|
*/
|
||||||
if (last_uniq_key(table,key_nr) &&
|
bool is_long_unique= table->s->key_info &&
|
||||||
|
table->s->key_info[key_nr].algorithm ==
|
||||||
|
HA_KEY_ALG_LONG_HASH;
|
||||||
|
if ((is_long_unique ?
|
||||||
|
/*
|
||||||
|
We have a long unique. Test that there are no in-engine
|
||||||
|
uniques and the current long unique is the last long unique.
|
||||||
|
*/
|
||||||
|
!(table->key_info[0].flags & HA_NOSAME) &&
|
||||||
|
last_uniq_key(table, table->s->key_info, key_nr) :
|
||||||
|
/*
|
||||||
|
We have a normal key - not a long unique.
|
||||||
|
Test is the current normal key is unique and
|
||||||
|
it is the last normal unique.
|
||||||
|
*/
|
||||||
|
last_uniq_key(table, table->key_info, key_nr)) &&
|
||||||
!table->file->referenced_by_foreign_key() &&
|
!table->file->referenced_by_foreign_key() &&
|
||||||
(!table->triggers || !table->triggers->has_delete_triggers()))
|
(!table->triggers || !table->triggers->has_delete_triggers()))
|
||||||
{
|
{
|
||||||
|
Reference in New Issue
Block a user