Skip to content

Commit 94f923b

Browse files
committed
MDEV-21786 mysqldump will forget sequence definition details on --no-data dump
- Original patch was contributed by Jani Tolonen <[email protected]> https://github.com/an3l/server/commits/bb-10.3-anel-MDEV-21786-dump-sequence which distinguishes data structure (linked list) of sequences from tables. - According to MDEV? added standard sql output to prevent future changes of sequences and disabled locks for sequences - Added test case for `MDEV-20070: mysqldump won't work correct on sequences` where table column depends on sequence value @TBD.
1 parent 7e07e38 commit 94f923b

File tree

4 files changed

+235
-31
lines changed

4 files changed

+235
-31
lines changed

client/mysqldump.c

Lines changed: 70 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -39,7 +39,7 @@
3939
** 10 Jun 2003: SET NAMES and --no-set-names by Alexander Barkov
4040
*/
4141

42-
#define DUMP_VERSION "10.17"
42+
#define DUMP_VERSION "10.18"
4343

4444
#include <my_global.h>
4545
#include <my_sys.h>
@@ -83,6 +83,7 @@
8383
#define IGNORE_NONE 0x00 /* no ignore */
8484
#define IGNORE_DATA 0x01 /* don't dump data for this table */
8585
#define IGNORE_INSERT_DELAYED 0x02 /* table doesn't support INSERT DELAYED */
86+
#define IGNORE_SEQUENCE_TABLE 0x04 /* catch the SEQUENCE*/
8687

8788
/* Chars needed to store LONGLONG, excluding trailing '\0'. */
8889
#define LONGLONG_LEN 20
@@ -2738,7 +2739,62 @@ static inline my_bool general_log_or_slow_log_tables(const char *db,
27382739
!my_strcasecmp(charset_info, table, "slow_log") ||
27392740
!my_strcasecmp(charset_info, table, "transaction_registry"));
27402741
}
2742+
/*
2743+
get_sequence_structure-- retrievs sequence structure, prints out corresponding
2744+
CREATE statement
2745+
ARGS
2746+
seq - sequence name
2747+
db - db name
2748+
2749+
RETURN
2750+
0 if ok, 1 if error
27412751
2752+
*/
2753+
2754+
static uint get_sequence_structure(const char *seq, const char *db)
2755+
{
2756+
2757+
char table_buff[NAME_LEN*2+3];
2758+
char *result_seq;
2759+
FILE *sql_file= md_result_file;
2760+
MYSQL_RES *result;
2761+
MYSQL_ROW row;
2762+
2763+
DBUG_ENTER("get_sequence_structure");
2764+
DBUG_PRINT("enter", ("db: %s sequence: %s", db, seq));
2765+
2766+
verbose_msg("-- Retrieving table structure for sequence %s...\n", seq);
2767+
2768+
result_seq= quote_name(seq, table_buff, 1);
2769+
// Sequences as tables share same flags
2770+
if (!opt_no_create_info)
2771+
{
2772+
char buff[20+FN_REFLEN];
2773+
my_snprintf(buff, sizeof(buff), "SHOW CREATE SEQUENCE %s", result_seq);
2774+
if (switch_character_set_results(mysql, "binary") ||
2775+
mysql_query_with_error_report(mysql, &result, buff) ||
2776+
switch_character_set_results(mysql, default_charset))
2777+
{
2778+
DBUG_RETURN(1);
2779+
}
2780+
2781+
print_comment(sql_file, 0,
2782+
"\n--\n-- Table structure for sequence %s\n--\n\n",
2783+
fix_for_comment(result_seq));
2784+
if (opt_drop)
2785+
{
2786+
fprintf(sql_file, "DROP SEQUENCE IF EXISTS %s;\n", result_seq);
2787+
check_io(sql_file);
2788+
}
2789+
2790+
row= mysql_fetch_row(result);
2791+
fprintf(sql_file, "%s;\n", row[1]);
2792+
2793+
// Sequences will not use inserts, so no need for REPLACE and LOCKS
2794+
mysql_free_result(result);
2795+
}
2796+
DBUG_RETURN(0);
2797+
}
27422798
/*
27432799
get_table_structure -- retrievs database structure, prints out corresponding
27442800
CREATE statement and fills out insert_pat if the table is the type we will
@@ -3720,6 +3776,16 @@ static void dump_table(char *table, char *db, const uchar *hash_key, size_t len)
37203776
MYSQL_ROW row;
37213777
DBUG_ENTER("dump_table");
37223778

3779+
/*
3780+
Check does table has a sequence structure and if has apply different sql queries
3781+
*/
3782+
if (check_if_ignore_table(table, table_type) & IGNORE_SEQUENCE_TABLE)
3783+
{
3784+
if (!get_sequence_structure(table, db))
3785+
{
3786+
DBUG_VOID_RETURN;
3787+
}
3788+
}
37233789
/*
37243790
Make sure you get the create table info before the following check for
37253791
--no-data flag below. Otherwise, the create table info won't be printed.
@@ -5688,7 +5754,7 @@ char check_if_ignore_table(const char *table_name, char *table_type)
56885754
/* Check memory for quote_for_like() */
56895755
DBUG_ASSERT(2*sizeof(table_name) < sizeof(show_name_buff));
56905756
my_snprintf(buff, sizeof(buff),
5691-
"SELECT engine FROM INFORMATION_SCHEMA.TABLES "
5757+
"SELECT engine, table_type FROM INFORMATION_SCHEMA.TABLES "
56925758
"WHERE table_schema = DATABASE() AND table_name = %s",
56935759
quote_for_equal(table_name, show_name_buff));
56945760
if (mysql_query_with_error_report(mysql, &res, buff))
@@ -5728,7 +5794,8 @@ char check_if_ignore_table(const char *table_name, char *table_type)
57285794
strcmp(table_type,"MEMORY"))
57295795
result= IGNORE_INSERT_DELAYED;
57305796
}
5731-
5797+
if (!strcmp(row[1],"SEQUENCE"))
5798+
result|= IGNORE_SEQUENCE_TABLE;
57325799
/*
57335800
If these two types, we do want to skip dumping the table
57345801
*/

mysql-test/main/mysqldump.result

Lines changed: 87 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -5904,4 +5904,91 @@ invisible int(11) YES NULL
59045904
a b c & $!@#$%^&*( ) int(11) YES 4 INVISIBLE
59055905
ds=~!@ \# $% ^ & * ( ) _ - = + int(11) YES 5 INVISIBLE
59065906
drop database d;
5907+
#
5908+
# MDEV-21786:
5909+
# myslqdump will forget sequence definition details on --no-data dump
5910+
#
5911+
create database d;
5912+
use d;
5913+
CREATE SEQUENCE s1 START WITH 100 INCREMENT BY 10 MINVALUE=100 MAXVALUE=1100 CYCLE;
5914+
CREATE SEQUENCE s2 START WITH 200 INCREMENT BY 20 MINVALUE=200 MAXVALUE=1200 CYCLE;
5915+
CREATE SEQUENCE s3 START WITH 300 INCREMENT BY 30 MINVALUE=300 MAXVALUE=1300 CYCLE;
5916+
CREATE SEQUENCE s4 START WITH 400 INCREMENT BY 40 MINVALUE=400 MAXVALUE=1400 CYCLE;
5917+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
5918+
NEXTVAL(s1) NEXTVAL(s2) NEXTVAL(s3) NEXTVAL(s4)
5919+
100 200 300 400
5920+
# Show create before dump
5921+
show create sequence s1;
5922+
Table Create Table
5923+
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
5924+
show create sequence s2;
5925+
Table Create Table
5926+
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
5927+
show create sequence s3;
5928+
Table Create Table
5929+
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
5930+
show create sequence s4;
5931+
Table Create Table
5932+
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
5933+
# Dump sequence without `--no-data`
5934+
# Restore from mysqldump
5935+
# Show create after restore
5936+
show create sequence s1;
5937+
Table Create Table
5938+
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
5939+
show create sequence s2;
5940+
Table Create Table
5941+
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
5942+
show create sequence s3;
5943+
Table Create Table
5944+
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
5945+
show create sequence s4;
5946+
Table Create Table
5947+
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
5948+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
5949+
NEXTVAL(s1) NEXTVAL(s2) NEXTVAL(s3) NEXTVAL(s4)
5950+
100 200 300 400
5951+
# Dump sequence with `--no-data`
5952+
# Restore from mysqldump
5953+
# Show create after restore `--no-data`
5954+
show create sequence s1;
5955+
Table Create Table
5956+
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
5957+
show create sequence s2;
5958+
Table Create Table
5959+
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
5960+
show create sequence s3;
5961+
Table Create Table
5962+
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
5963+
show create sequence s4;
5964+
Table Create Table
5965+
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
5966+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
5967+
NEXTVAL(s1) NEXTVAL(s2) NEXTVAL(s3) NEXTVAL(s4)
5968+
100 200 300 400
5969+
drop sequence s1, s2, s3, s4;
5970+
drop database d;
5971+
#
5972+
# MDEV-20070
5973+
# mysqldump won't work correct on sequences
5974+
#
5975+
DROP DATABASE IF EXISTS test1;
5976+
Warnings:
5977+
Note 1008 Can't drop database 'test1'; database doesn't exist
5978+
DROP DATABASE IF EXISTS test2;
5979+
Warnings:
5980+
Note 1008 Can't drop database 'test2'; database doesn't exist
5981+
CREATE DATABASE test1;
5982+
CREATE DATABASE test2;
5983+
USE test1;
5984+
CREATE SEQUENCE seq_t_i INCREMENT 5 START WITH 1;
5985+
CREATE TABLE t(
5986+
i integer DEFAULT nextval(seq_t_i),
5987+
j integer
5988+
);
5989+
INSERT INTO t VALUES (1,1),(2,2),(3,3),(4,4);
5990+
# Dump database 1
5991+
# Restore from database 1 to database 2
5992+
DROP DATABASE IF EXISTS test1;
5993+
DROP DATABASE IF EXISTS test2;
59075994
# End of 10.3 tests

mysql-test/main/mysqldump.test

Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2793,4 +2793,80 @@ select * from t3;
27932793
desc t3;
27942794
drop database d;
27952795

2796+
--echo #
2797+
--echo # MDEV-21786:
2798+
--echo # myslqdump will forget sequence definition details on --no-data dump
2799+
--echo #
2800+
create database d;
2801+
use d;
2802+
2803+
CREATE SEQUENCE s1 START WITH 100 INCREMENT BY 10 MINVALUE=100 MAXVALUE=1100 CYCLE;
2804+
CREATE SEQUENCE s2 START WITH 200 INCREMENT BY 20 MINVALUE=200 MAXVALUE=1200 CYCLE;
2805+
CREATE SEQUENCE s3 START WITH 300 INCREMENT BY 30 MINVALUE=300 MAXVALUE=1300 CYCLE;
2806+
CREATE SEQUENCE s4 START WITH 400 INCREMENT BY 40 MINVALUE=400 MAXVALUE=1400 CYCLE;
2807+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
2808+
2809+
--echo # Show create before dump
2810+
show create sequence s1;
2811+
show create sequence s2;
2812+
show create sequence s3;
2813+
show create sequence s4;
2814+
2815+
--echo # Dump sequence without `--no-data`
2816+
--exec $MYSQL_DUMP --databases d > $MYSQLTEST_VARDIR/tmp/dump1.sql
2817+
--echo # Restore from mysqldump
2818+
--exec $MYSQL -Dd < $MYSQLTEST_VARDIR/tmp/dump1.sql
2819+
--remove_file $MYSQLTEST_VARDIR/tmp/dump1.sql
2820+
2821+
--echo # Show create after restore
2822+
show create sequence s1;
2823+
show create sequence s2;
2824+
show create sequence s3;
2825+
show create sequence s4;
2826+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
2827+
2828+
--echo # Dump sequence with `--no-data`
2829+
--exec $MYSQL_DUMP --databases d --no-data > $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
2830+
--echo # Restore from mysqldump
2831+
--exec $MYSQL -Dd < $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
2832+
--remove_file $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
2833+
2834+
--echo # Show create after restore `--no-data`
2835+
show create sequence s1;
2836+
show create sequence s2;
2837+
show create sequence s3;
2838+
show create sequence s4;
2839+
SELECT NEXTVAL(s1),NEXTVAL(s2),NEXTVAL(s3), NEXTVAL(s4);
2840+
2841+
drop sequence s1, s2, s3, s4;
2842+
drop database d;
2843+
2844+
--echo #
2845+
--echo # MDEV-20070
2846+
--echo # mysqldump won't work correct on sequences
2847+
--echo #
2848+
2849+
DROP DATABASE IF EXISTS test1;
2850+
DROP DATABASE IF EXISTS test2;
2851+
CREATE DATABASE test1;
2852+
CREATE DATABASE test2;
2853+
USE test1;
2854+
CREATE SEQUENCE seq_t_i INCREMENT 5 START WITH 1;
2855+
CREATE TABLE t(
2856+
i integer DEFAULT nextval(seq_t_i),
2857+
j integer
2858+
);
2859+
INSERT INTO t VALUES (1,1),(2,2),(3,3),(4,4);
2860+
2861+
--echo # Dump database 1
2862+
--exec $MYSQL_DUMP test1 > $MYSQLTEST_VARDIR/tmp/dumptest1.sql
2863+
--echo # Restore from database 1 to database 2
2864+
2865+
--error 1
2866+
--exec $MYSQL test2 < $MYSQLTEST_VARDIR/tmp/dumptest1.sql
2867+
2868+
--remove_file $MYSQLTEST_VARDIR/tmp/dumptest1.sql
2869+
DROP DATABASE IF EXISTS test1;
2870+
DROP DATABASE IF EXISTS test2;
2871+
27962872
--echo # End of 10.3 tests

mysql-test/suite/sql_sequence/mysqldump.result

Lines changed: 2 additions & 28 deletions
Original file line numberDiff line numberDiff line change
@@ -2,20 +2,7 @@ CREATE SEQUENCE a1 engine=aria;
22
CREATE TABLE t1(a INT, KEY (a)) KEY_BLOCK_SIZE=1024;
33
insert into t1 values (1),(2);
44
CREATE SEQUENCE x1 engine=innodb;
5-
/*!40101 SET @saved_cs_client = @@character_set_client */;
6-
/*!40101 SET character_set_client = utf8 */;
7-
CREATE TABLE `a1` (
8-
`next_not_cached_value` bigint(21) NOT NULL,
9-
`minimum_value` bigint(21) NOT NULL,
10-
`maximum_value` bigint(21) NOT NULL,
11-
`start_value` bigint(21) NOT NULL COMMENT 'start value when sequences is created or value if RESTART is used',
12-
`increment` bigint(21) NOT NULL COMMENT 'increment value',
13-
`cache_size` bigint(21) unsigned NOT NULL,
14-
`cycle_option` tinyint(1) unsigned NOT NULL COMMENT '0 if no cycles are allowed, 1 if the sequence should begin a new cycle when maximum_value is passed',
15-
`cycle_count` bigint(21) NOT NULL COMMENT 'How many cycles have been done'
16-
) ENGINE=Aria SEQUENCE=1;
17-
/*!40101 SET character_set_client = @saved_cs_client */;
18-
INSERT INTO `a1` VALUES (1,1,9223372036854775806,1,1,1000,0,0);
5+
CREATE SEQUENCE `a1` start with 1 minvalue 1 maxvalue 9223372036854775806 increment by 1 cache 1000 nocycle ENGINE=Aria;
196
/*!40101 SET @saved_cs_client = @@character_set_client */;
207
/*!40101 SET character_set_client = utf8 */;
218
CREATE TABLE `t1` (
@@ -24,20 +11,7 @@ CREATE TABLE `t1` (
2411
) ENGINE=MyISAM DEFAULT CHARSET=latin1 KEY_BLOCK_SIZE=1024;
2512
/*!40101 SET character_set_client = @saved_cs_client */;
2613
INSERT INTO `t1` VALUES (1),(2);
27-
/*!40101 SET @saved_cs_client = @@character_set_client */;
28-
/*!40101 SET character_set_client = utf8 */;
29-
CREATE TABLE `x1` (
30-
`next_not_cached_value` bigint(21) NOT NULL,
31-
`minimum_value` bigint(21) NOT NULL,
32-
`maximum_value` bigint(21) NOT NULL,
33-
`start_value` bigint(21) NOT NULL COMMENT 'start value when sequences is created or value if RESTART is used',
34-
`increment` bigint(21) NOT NULL COMMENT 'increment value',
35-
`cache_size` bigint(21) unsigned NOT NULL,
36-
`cycle_option` tinyint(1) unsigned NOT NULL COMMENT '0 if no cycles are allowed, 1 if the sequence should begin a new cycle when maximum_value is passed',
37-
`cycle_count` bigint(21) NOT NULL COMMENT 'How many cycles have been done'
38-
) ENGINE=InnoDB SEQUENCE=1;
39-
/*!40101 SET character_set_client = @saved_cs_client */;
40-
INSERT INTO `x1` VALUES (1,1,9223372036854775806,1,1,1000,0,0);
14+
CREATE SEQUENCE `x1` start with 1 minvalue 1 maxvalue 9223372036854775806 increment by 1 cache 1000 nocycle ENGINE=InnoDB;
4115
DROP TABLE a1,t1,x1;
4216
set default_storage_engine=InnoDB;
4317
create sequence t1;

0 commit comments

Comments
 (0)