Commit 22f7190e authored by Monty's avatar Monty

MDEV-28074 mysqldump --order-by-size

Author: Erki Aring
parent 161fd2d2
...@@ -121,8 +121,8 @@ static my_bool verbose= 0, opt_no_create_info= 0, opt_no_data= 0, opt_no_data_m ...@@ -121,8 +121,8 @@ static my_bool verbose= 0, opt_no_create_info= 0, opt_no_data= 0, opt_no_data_m
opt_autocommit=0,opt_disable_keys=1,opt_xml=0, opt_autocommit=0,opt_disable_keys=1,opt_xml=0,
opt_delete_master_logs=0, tty_password=0, opt_delete_master_logs=0, tty_password=0,
opt_single_transaction=0, opt_comments= 0, opt_compact= 0, opt_single_transaction=0, opt_comments= 0, opt_compact= 0,
opt_hex_blob=0, opt_order_by_primary=0, opt_ignore=0, opt_hex_blob=0, opt_order_by_primary=0, opt_order_by_size = 0,
opt_complete_insert= 0, opt_drop_database= 0, opt_ignore=0, opt_complete_insert= 0, opt_drop_database= 0,
opt_replace_into= 0, opt_replace_into= 0,
opt_dump_triggers= 0, opt_routines=0, opt_tz_utc=1, opt_dump_triggers= 0, opt_routines=0, opt_tz_utc=1,
opt_slave_apply= 0, opt_slave_apply= 0,
...@@ -504,6 +504,10 @@ static struct my_option my_long_options[] = ...@@ -504,6 +504,10 @@ static struct my_option my_long_options[] =
{"order-by-primary", OPT_ORDER_BY_PRIMARY, {"order-by-primary", OPT_ORDER_BY_PRIMARY,
"Sorts each table's rows by primary key, or first unique key, if such a key exists. Useful when dumping a MyISAM table to be loaded into an InnoDB table, but will make the dump itself take considerably longer.", "Sorts each table's rows by primary key, or first unique key, if such a key exists. Useful when dumping a MyISAM table to be loaded into an InnoDB table, but will make the dump itself take considerably longer.",
&opt_order_by_primary, &opt_order_by_primary, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0}, &opt_order_by_primary, &opt_order_by_primary, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0},
{"order-by-size", 0,
"Dump tables in the order of their size, smaller first. Useful when using --single-transaction on tables which get truncated often. "
"Dumping smaller tables first reduces chances of often truncated tables to get altered before being dumped.",
&opt_order_by_size, &opt_order_by_size, 0, GET_BOOL, NO_ARG, 0, 0, 0, 0, 0, 0},
{"password", 'p', {"password", 'p',
"Password to use when connecting to server. If password is not given it's solicited on the tty.", "Password to use when connecting to server. If password is not given it's solicited on the tty.",
0, 0, 0, GET_STR, OPT_ARG, 0, 0, 0, 0, 0, 0}, 0, 0, 0, GET_STR, OPT_ARG, 0, 0, 0, 0, 0, 0},
...@@ -1339,6 +1343,12 @@ static int get_options(int *argc, char ***argv) ...@@ -1339,6 +1343,12 @@ static int get_options(int *argc, char ***argv)
MY_CS_PRIMARY, MY_CS_PRIMARY,
MYF(MY_UTF8_IS_UTF8MB3 | MY_WME)))) MYF(MY_UTF8_IS_UTF8MB3 | MY_WME))))
exit(1); exit(1);
if (opt_order_by_size && (*argc > 1 && !opt_databases))
{
fprintf(stderr, "%s: --order-by-size can't be used when dumping selected tables\n",
my_progname_short);
return EX_USAGE;
}
if ((*argc < 1 && (!opt_alldbs && !opt_system)) || (*argc > 0 && opt_alldbs)) if ((*argc < 1 && (!opt_alldbs && !opt_system)) || (*argc > 0 && opt_alldbs))
{ {
short_usage(stderr); short_usage(stderr);
...@@ -4572,12 +4582,18 @@ static void dump_table(const char *table, const char *db, const uchar *hash_key, ...@@ -4572,12 +4582,18 @@ static void dump_table(const char *table, const char *db, const uchar *hash_key,
static char *getTableName(int reset, int want_sequences) static char *getTableName(int reset, int want_sequences)
{ {
MYSQL_ROW row; MYSQL_ROW row;
const char *query;
if (!get_table_name_result) if (!get_table_name_result)
{ {
if (mysql_get_server_version(mysql) >= FIRST_SEQUENCE_VERSION) if (opt_order_by_size || mysql_get_server_version(mysql) >= FIRST_SEQUENCE_VERSION)
{ {
const char *query= "SHOW FULL TABLES"; if (opt_order_by_size) {
query= "SELECT table_name, table_type FROM INFORMATION_SCHEMA.TABLES "
"WHERE table_schema = DATABASE() ORDER BY data_length, table_name";
} else {
query = "SHOW FULL TABLES";
}
if (mysql_query_with_error_report(mysql, 0, query)) if (mysql_query_with_error_report(mysql, 0, query))
return (NULL); return (NULL);
......
...@@ -1549,6 +1549,24 @@ table, but will make the dump operation take considerably longer\&. ...@@ -1549,6 +1549,24 @@ table, but will make the dump operation take considerably longer\&.
.sp -1 .sp -1
.IP \(bu 2.3 .IP \(bu 2.3
.\} .\}
.\" mysqldump: order-by-size option
.\" order-by-size option: mysqldump
\fB\-\-order\-by\-size\fR
.sp
Dump each table according to their size, smallest first\&. Useful when using \-\-single\-transaction on tables which get truncated/altered often\&.
.sp
The assumption here is that smaller tables get truncated more often, and by doing dumping those first, this reduces the chance that a \-\-single\-transaction
dump will fail with with 'Table definition has changed, please retry transaction'\&.
.RE
.sp
.RS 4
.ie n \{\
\h'-04'\(bu\h'+03'\c
.\}
.el \{\
.sp -1
.IP \(bu 2.3
.\}
.\" mysqldump: password option .\" mysqldump: password option
.\" password option: mysqldump .\" password option: mysqldump
\fB\-\-password[=\fR\fB\fIpassword\fR\fR\fB]\fR, \fB\-\-password[=\fR\fB\fIpassword\fR\fR\fB]\fR,
......
# --order-by-size:
CREATE TABLE t1 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t2 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t3 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t4 (a MEDIUMBLOB) ENGINE=InnoDB;
INSERT INTO t1 VALUES (REPEAT('E',65536*4));
INSERT INTO t2 VALUES (REPEAT('E',65536*3));
INSERT INTO t3 VALUES (REPEAT('E',65536*2));
INSERT INTO t4 VALUES (REPEAT('E',65536*1));
ANALYZE TABLE t1, t2, t3, t4;
Table Op Msg_type Msg_text
test.t1 analyze status Engine-independent statistics collected
test.t1 analyze Warning Engine-independent statistics are not collected for column 'a'
test.t1 analyze status OK
test.t2 analyze status Engine-independent statistics collected
test.t2 analyze Warning Engine-independent statistics are not collected for column 'a'
test.t2 analyze status OK
test.t3 analyze status Engine-independent statistics collected
test.t3 analyze Warning Engine-independent statistics are not collected for column 'a'
test.t3 analyze status OK
test.t4 analyze status Engine-independent statistics collected
test.t4 analyze Warning Engine-independent statistics are not collected for column 'a'
test.t4 analyze status OK
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t4` (
`a` mediumblob DEFAULT NULL
);
/*!40101 SET character_set_client = @saved_cs_client */;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t3` (
`a` mediumblob DEFAULT NULL
);
/*!40101 SET character_set_client = @saved_cs_client */;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t2` (
`a` mediumblob DEFAULT NULL
);
/*!40101 SET character_set_client = @saved_cs_client */;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t1` (
`a` mediumblob DEFAULT NULL
);
/*!40101 SET character_set_client = @saved_cs_client */;
DROP TABLE t4, t3, t2, t1;
--source include/not_embedded.inc
--source include/have_innodb.inc
--echo # --order-by-size:
CREATE TABLE t1 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t2 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t3 (a MEDIUMBLOB) ENGINE=InnoDB;
CREATE TABLE t4 (a MEDIUMBLOB) ENGINE=InnoDB;
INSERT INTO t1 VALUES (REPEAT('E',65536*4));
INSERT INTO t2 VALUES (REPEAT('E',65536*3));
INSERT INTO t3 VALUES (REPEAT('E',65536*2));
INSERT INTO t4 VALUES (REPEAT('E',65536*1));
ANALYZE TABLE t1, t2, t3, t4;
--exec $MYSQL_DUMP --compact --skip-opt --skip-comments --no-data --order-by-size test
DROP TABLE t4, t3, t2, 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