Commit 81870e49 authored by Anel Husakovic's avatar Anel Husakovic

MDEV-21786 mysqldump will forget sequence definition details on --no-data dump

- Original patch was contributed by Jani Tolonen <jani.k.tolonen@gmail.com>
https://github.com/an3l/server/commits/bb-10.3-anel-MDEV-21786-dump-sequence
which distinguishes data structure (linked list) of sequences from
tables.
- 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.
- Restore sequence last value in the following way:
  - Find `next_not_cached_value` and use it to `setval()`
  - We just need for logical restore, so don't execute `setval()`
  - `setval()` should be showed also in case of `--no-data` option.

Reviewed-by: daniel@mariadb.org
parent e3d692aa
......@@ -39,7 +39,7 @@
** 10 Jun 2003: SET NAMES and --no-set-names by Alexander Barkov
*/
#define DUMP_VERSION "10.17"
#define DUMP_VERSION "10.18"
#include <my_global.h>
#include <my_sys.h>
......@@ -83,6 +83,7 @@
#define IGNORE_NONE 0x00 /* no ignore */
#define IGNORE_DATA 0x01 /* don't dump data for this table */
#define IGNORE_INSERT_DELAYED 0x02 /* table doesn't support INSERT DELAYED */
#define IGNORE_SEQUENCE_TABLE 0x04 /* catch the SEQUENCE*/
/* Chars needed to store LONGLONG, excluding trailing '\0'. */
#define LONGLONG_LEN 20
......@@ -2738,7 +2739,68 @@ static inline my_bool general_log_or_slow_log_tables(const char *db,
!my_strcasecmp(charset_info, table, "slow_log") ||
!my_strcasecmp(charset_info, table, "transaction_registry"));
}
/*
get_sequence_structure-- retrievs sequence structure, prints out corresponding
CREATE statement
ARGS
seq - sequence name
db - db name
*/
static void get_sequence_structure(const char *seq, const char *db)
{
char table_buff[NAME_LEN*2+3];
char *result_seq;
FILE *sql_file= md_result_file;
MYSQL_RES *result;
MYSQL_ROW row;
DBUG_ENTER("get_sequence_structure");
DBUG_PRINT("enter", ("db: %s sequence: %s", db, seq));
verbose_msg("-- Retrieving sequence structure for %s...\n", seq);
result_seq= quote_name(seq, table_buff, 1);
// Sequences as tables share same flags
if (!opt_no_create_info)
{
char buff[20+FN_REFLEN];
my_snprintf(buff, sizeof(buff), "SHOW CREATE SEQUENCE %s", result_seq);
if (mysql_query_with_error_report(mysql, &result, buff))
{
DBUG_VOID_RETURN;
}
print_comment(sql_file, 0,
"\n--\n-- Sequence structure for %s\n--\n\n",
fix_for_comment(result_seq));
if (opt_drop)
{
fprintf(sql_file, "DROP SEQUENCE IF EXISTS %s;\n", result_seq);
check_io(sql_file);
}
row= mysql_fetch_row(result);
fprintf(sql_file, "%s;\n", row[1]);
mysql_free_result(result);
// Restore next not cached value from sequence
my_snprintf(buff, sizeof(buff), "SELECT next_not_cached_value FROM %s", result_seq);
if (mysql_query_with_error_report(mysql, &result, buff))
{
DBUG_VOID_RETURN;
}
row= mysql_fetch_row(result);
if (row[0])
{
fprintf(sql_file, "SELECT SETVAL(%s, %s, 0);\n", result_seq, row[0]);
}
// Sequences will not use inserts, so no need for REPLACE and LOCKS
mysql_free_result(result);
}
DBUG_VOID_RETURN;
}
/*
get_table_structure -- retrievs database structure, prints out corresponding
CREATE statement and fills out insert_pat if the table is the type we will
......@@ -3720,6 +3782,14 @@ static void dump_table(char *table, char *db, const uchar *hash_key, size_t len)
MYSQL_ROW row;
DBUG_ENTER("dump_table");
/*
Check does table has a sequence structure and if has apply different sql queries
*/
if (check_if_ignore_table(table, table_type) & IGNORE_SEQUENCE_TABLE)
{
get_sequence_structure(table, db);
DBUG_VOID_RETURN;
}
/*
Make sure you get the create table info before the following check for
--no-data flag below. Otherwise, the create table info won't be printed.
......@@ -5688,7 +5758,7 @@ char check_if_ignore_table(const char *table_name, char *table_type)
/* Check memory for quote_for_like() */
DBUG_ASSERT(2*sizeof(table_name) < sizeof(show_name_buff));
my_snprintf(buff, sizeof(buff),
"SELECT engine FROM INFORMATION_SCHEMA.TABLES "
"SELECT engine, table_type FROM INFORMATION_SCHEMA.TABLES "
"WHERE table_schema = DATABASE() AND table_name = %s",
quote_for_equal(table_name, show_name_buff));
if (mysql_query_with_error_report(mysql, &res, buff))
......@@ -5728,7 +5798,8 @@ char check_if_ignore_table(const char *table_name, char *table_type)
strcmp(table_type,"MEMORY"))
result= IGNORE_INSERT_DELAYED;
}
if (!strcmp(row[1],"SEQUENCE"))
result|= IGNORE_SEQUENCE_TABLE;
/*
If these two types, we do want to skip dumping the table
*/
......
......@@ -5904,4 +5904,122 @@ invisible int(11) YES NULL
a b c & $!@#$%^&*( ) int(11) YES 4 INVISIBLE
ds=~!@ \# $% ^ & * ( ) _ - = + int(11) YES 5 INVISIBLE
drop database d;
#
# MDEV-21786:
# mysqldump will forget sequence definition details on --no-data dump
#
create database d;
CREATE SEQUENCE d.s1 START WITH 100 INCREMENT BY 10 MINVALUE=100 MAXVALUE=1100 CYCLE;
CREATE SEQUENCE d.s2 START WITH 200 INCREMENT BY 20 MINVALUE=200 MAXVALUE=1200 CYCLE;
CREATE SEQUENCE d.s3 START WITH 300 INCREMENT BY 30 MINVALUE=300 MAXVALUE=1300 CYCLE;
CREATE SEQUENCE d.s4 START WITH 400 INCREMENT BY 40 MINVALUE=400 MAXVALUE=1400 CYCLE;
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
NEXTVAL(d.s1) NEXTVAL(d.s2) NEXTVAL(d.s3) NEXTVAL(d.s4)
100 200 300 400
# Show create before dump
show create sequence d.s1;
Table Create Table
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s2;
Table Create Table
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s3;
Table Create Table
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s4;
Table Create Table
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
# Dump sequence without `--no-data`
# Restore from mysqldump
SETVAL(`s1`, 1101, 0)
1101
SETVAL(`s2`, 1201, 0)
1201
SETVAL(`s3`, 1301, 0)
1301
SETVAL(`s4`, 1401, 0)
1401
# Show create after restore
show create sequence d.s1;
Table Create Table
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s2;
Table Create Table
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s3;
Table Create Table
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s4;
Table Create Table
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
NEXTVAL(d.s1) NEXTVAL(d.s2) NEXTVAL(d.s3) NEXTVAL(d.s4)
100 200 300 400
# Dump sequence with `--no-data`
# Restore from mysqldump
SETVAL(`s1`, 1101, 0)
1101
SETVAL(`s2`, 1201, 0)
1201
SETVAL(`s3`, 1301, 0)
1301
SETVAL(`s4`, 1401, 0)
1401
# Show create after restore `--no-data`
show create sequence d.s1;
Table Create Table
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s2;
Table Create Table
s2 CREATE SEQUENCE `s2` start with 200 minvalue 200 maxvalue 1200 increment by 20 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s3;
Table Create Table
s3 CREATE SEQUENCE `s3` start with 300 minvalue 300 maxvalue 1300 increment by 30 cache 1000 cycle ENGINE=MyISAM
show create sequence d.s4;
Table Create Table
s4 CREATE SEQUENCE `s4` start with 400 minvalue 400 maxvalue 1400 increment by 40 cache 1000 cycle ENGINE=MyISAM
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
NEXTVAL(d.s1) NEXTVAL(d.s2) NEXTVAL(d.s3) NEXTVAL(d.s4)
100 200 300 400
# Restore to different database than original
create database d2;
SETVAL(`s1`, 1101, 0)
1101
SETVAL(`s2`, 1201, 0)
1201
SETVAL(`s3`, 1301, 0)
1301
SETVAL(`s4`, 1401, 0)
1401
show create sequence d2.s1;
Table Create Table
s1 CREATE SEQUENCE `s1` start with 100 minvalue 100 maxvalue 1100 increment by 10 cache 1000 cycle ENGINE=MyISAM
drop sequence d.s1, d.s2, d.s3, d.s4;
drop database d;
drop database d2;
#
# MDEV-20070
# mysqldump won't work correct on sequences
#
DROP DATABASE IF EXISTS test1;
Warnings:
Note 1008 Can't drop database 'test1'; database doesn't exist
DROP DATABASE IF EXISTS test2;
Warnings:
Note 1008 Can't drop database 'test2'; database doesn't exist
CREATE DATABASE test1;
CREATE DATABASE test2;
USE test1;
CREATE SEQUENCE seq_t_i INCREMENT 5 START WITH 1;
CREATE TABLE t(
i integer DEFAULT nextval(seq_t_i),
j integer
);
INSERT INTO t VALUES (1,1),(2,2),(3,3),(4,4);
# Dump database 1
# Restore from database 1 to database 2
SETVAL(`seq_t_i`, 1, 0)
1
DROP DATABASE IF EXISTS test1;
DROP DATABASE IF EXISTS test2;
# End of 10.3 tests
......@@ -2793,4 +2793,87 @@ select * from t3;
desc t3;
drop database d;
--echo #
--echo # MDEV-21786:
--echo # mysqldump will forget sequence definition details on --no-data dump
--echo #
create database d;
CREATE SEQUENCE d.s1 START WITH 100 INCREMENT BY 10 MINVALUE=100 MAXVALUE=1100 CYCLE;
CREATE SEQUENCE d.s2 START WITH 200 INCREMENT BY 20 MINVALUE=200 MAXVALUE=1200 CYCLE;
CREATE SEQUENCE d.s3 START WITH 300 INCREMENT BY 30 MINVALUE=300 MAXVALUE=1300 CYCLE;
CREATE SEQUENCE d.s4 START WITH 400 INCREMENT BY 40 MINVALUE=400 MAXVALUE=1400 CYCLE;
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
--echo # Show create before dump
show create sequence d.s1;
show create sequence d.s2;
show create sequence d.s3;
show create sequence d.s4;
--echo # Dump sequence without `--no-data`
--exec $MYSQL_DUMP --databases d > $MYSQLTEST_VARDIR/tmp/dump1.sql
--echo # Restore from mysqldump
--exec $MYSQL -Dd < $MYSQLTEST_VARDIR/tmp/dump1.sql
--remove_file $MYSQLTEST_VARDIR/tmp/dump1.sql
--echo # Show create after restore
show create sequence d.s1;
show create sequence d.s2;
show create sequence d.s3;
show create sequence d.s4;
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
--echo # Dump sequence with `--no-data`
--exec $MYSQL_DUMP --databases d --no-data > $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
--echo # Restore from mysqldump
--exec $MYSQL -Dd < $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
--remove_file $MYSQLTEST_VARDIR/tmp/dump-no-data.sql
--echo # Show create after restore `--no-data`
show create sequence d.s1;
show create sequence d.s2;
show create sequence d.s3;
show create sequence d.s4;
SELECT NEXTVAL(d.s1),NEXTVAL(d.s2),NEXTVAL(d.s3), NEXTVAL(d.s4);
--echo # Restore to different database than original
--exec $MYSQL_DUMP d > $MYSQLTEST_VARDIR/tmp/dumpd.sql
create database d2;
--exec $MYSQL d2 < $MYSQLTEST_VARDIR/tmp/dumpd.sql
--remove_file $MYSQLTEST_VARDIR/tmp/dumpd.sql
show create sequence d2.s1;
drop sequence d.s1, d.s2, d.s3, d.s4;
drop database d;
drop database d2;
--echo #
--echo # MDEV-20070
--echo # mysqldump won't work correct on sequences
--echo #
DROP DATABASE IF EXISTS test1;
DROP DATABASE IF EXISTS test2;
CREATE DATABASE test1;
CREATE DATABASE test2;
USE test1;
CREATE SEQUENCE seq_t_i INCREMENT 5 START WITH 1;
CREATE TABLE t(
i integer DEFAULT nextval(seq_t_i),
j integer
);
INSERT INTO t VALUES (1,1),(2,2),(3,3),(4,4);
--echo # Dump database 1
--exec $MYSQL_DUMP test1 > $MYSQLTEST_VARDIR/tmp/dumptest1.sql
--echo # Restore from database 1 to database 2
--error 1
--exec $MYSQL test2 < $MYSQLTEST_VARDIR/tmp/dumptest1.sql
--remove_file $MYSQLTEST_VARDIR/tmp/dumptest1.sql
DROP DATABASE IF EXISTS test1;
DROP DATABASE IF EXISTS test2;
--echo # End of 10.3 tests
......@@ -2,20 +2,8 @@ CREATE SEQUENCE a1 engine=aria;
CREATE TABLE t1(a INT, KEY (a)) KEY_BLOCK_SIZE=1024;
insert into t1 values (1),(2);
CREATE SEQUENCE x1 engine=innodb;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `a1` (
`next_not_cached_value` bigint(21) NOT NULL,
`minimum_value` bigint(21) NOT NULL,
`maximum_value` bigint(21) NOT NULL,
`start_value` bigint(21) NOT NULL COMMENT 'start value when sequences is created or value if RESTART is used',
`increment` bigint(21) NOT NULL COMMENT 'increment value',
`cache_size` bigint(21) unsigned NOT NULL,
`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',
`cycle_count` bigint(21) NOT NULL COMMENT 'How many cycles have been done'
) ENGINE=Aria SEQUENCE=1;
/*!40101 SET character_set_client = @saved_cs_client */;
INSERT INTO `a1` VALUES (1,1,9223372036854775806,1,1,1000,0,0);
CREATE SEQUENCE `a1` start with 1 minvalue 1 maxvalue 9223372036854775806 increment by 1 cache 1000 nocycle ENGINE=Aria;
SELECT SETVAL(`a1`, 1, 0);
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t1` (
......@@ -24,20 +12,8 @@ CREATE TABLE `t1` (
) ENGINE=MyISAM DEFAULT CHARSET=latin1 KEY_BLOCK_SIZE=1024;
/*!40101 SET character_set_client = @saved_cs_client */;
INSERT INTO `t1` VALUES (1),(2);
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `x1` (
`next_not_cached_value` bigint(21) NOT NULL,
`minimum_value` bigint(21) NOT NULL,
`maximum_value` bigint(21) NOT NULL,
`start_value` bigint(21) NOT NULL COMMENT 'start value when sequences is created or value if RESTART is used',
`increment` bigint(21) NOT NULL COMMENT 'increment value',
`cache_size` bigint(21) unsigned NOT NULL,
`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',
`cycle_count` bigint(21) NOT NULL COMMENT 'How many cycles have been done'
) ENGINE=InnoDB SEQUENCE=1;
/*!40101 SET character_set_client = @saved_cs_client */;
INSERT INTO `x1` VALUES (1,1,9223372036854775806,1,1,1000,0,0);
CREATE SEQUENCE `x1` start with 1 minvalue 1 maxvalue 9223372036854775806 increment by 1 cache 1000 nocycle ENGINE=InnoDB;
SELECT SETVAL(`x1`, 1, 0);
DROP TABLE a1,t1,x1;
set default_storage_engine=InnoDB;
create sequence t1;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment