Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
M
MariaDB
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
nexedi
MariaDB
Commits
d249761a
Commit
d249761a
authored
Sep 17, 2022
by
Sergei Golubchik
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
MDEV-16029 mysqldump: dump and restore historical data
parent
a39b4848
Changes
3
Hide whitespace changes
Inline
Side-by-side
Showing
3 changed files
with
303 additions
and
12 deletions
+303
-12
client/mysqldump.c
client/mysqldump.c
+59
-12
mysql-test/suite/versioning/r/data.result
mysql-test/suite/versioning/r/data.result
+126
-0
mysql-test/suite/versioning/t/data.test
mysql-test/suite/versioning/t/data.test
+118
-0
No files found.
client/mysqldump.c
View file @
d249761a
...
...
@@ -130,7 +130,7 @@ static my_bool verbose= 0, opt_no_create_info= 0, opt_no_data= 0, opt_no_data_m
opt_events
=
0
,
opt_comments_used
=
0
,
opt_alltspcs
=
0
,
opt_notspcs
=
0
,
opt_logging
,
opt_header
=
0
,
opt_drop_trigger
=
0
;
opt_drop_trigger
=
0
,
opt_dump_history
=
0
;
#define OPT_SYSTEM_ALL 1
#define OPT_SYSTEM_USERS 2
#define OPT_SYSTEM_PLUGINS 4
...
...
@@ -353,6 +353,8 @@ static struct my_option my_long_options[] =
"'/*!40000 ALTER TABLE tb_name DISABLE KEYS */; and '/*!40000 ALTER "
"TABLE tb_name ENABLE KEYS */; will be put in the output."
,
&
opt_disable_keys
,
&
opt_disable_keys
,
0
,
GET_BOOL
,
NO_ARG
,
1
,
0
,
0
,
0
,
0
,
0
},
{
"dump-history"
,
'H'
,
"Dump tables with history"
,
&
opt_dump_history
,
&
opt_dump_history
,
0
,
GET_BOOL
,
NO_ARG
,
0
,
0
,
0
,
0
,
0
,
0
},
{
"dump-slave"
,
OPT_MYSQLDUMP_SLAVE_DATA
,
"This causes the binary log position and filename of the master to be "
"appended to the dumped data output. Setting the value to 1, will print"
...
...
@@ -1355,6 +1357,24 @@ static int get_options(int *argc, char ***argv)
fprintf
(
stderr
,
"%s: --xml can't be used with --tab.
\n
"
,
my_progname_short
);
return
(
EX_USAGE
);
}
if
(
opt_xml
&&
opt_dump_history
)
{
fprintf
(
stderr
,
"%s: --xml can't be used with --dump-history.
\n
"
,
my_progname_short
);
return
(
EX_USAGE
);
}
if
(
opt_replace_into
&&
opt_dump_history
)
{
fprintf
(
stderr
,
"%s: --dump-history can't be used with --replace.
\n
"
,
my_progname_short
);
return
(
EX_USAGE
);
}
if
(
opt_asof_timestamp
&&
opt_dump_history
)
{
fprintf
(
stderr
,
"%s: --dump-history can't be used with --as-of.
\n
"
,
my_progname_short
);
return
(
EX_USAGE
);
}
if
(
opt_asof_timestamp
&&
strchr
(
opt_asof_timestamp
,
'\''
))
{
fprintf
(
stderr
,
"%s: Incorrect DATETIME value: '%s'
\n
"
,
...
...
@@ -3148,7 +3168,7 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
if
(
versioned
)
{
if
(
!
opt_asof_timestamp
)
if
(
!
opt_asof_timestamp
&&
!
opt_dump_history
)
versioned
=
NULL
;
else
{
...
...
@@ -3180,6 +3200,7 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
if
(
!
opt_xml
&&
!
mysql_query_with_error_report
(
mysql
,
0
,
query_buff
))
{
int
vers_hidden
=
opt_dump_history
&&
versioned
&&
*
versioned
;
/* using SHOW CREATE statement */
if
(
!
opt_no_create_info
)
{
...
...
@@ -3377,8 +3398,10 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
dynstr_free
(
&
create_table_str
);
mysql_free_result
(
result
);
}
my_snprintf
(
query_buff
,
sizeof
(
query_buff
),
"show fields from %s"
,
result_table
);
my_snprintf
(
query_buff
,
sizeof
(
query_buff
),
"select column_name, extra, generation_expression "
"from information_schema.columns where table_schema=database() "
"and table_name=%s"
,
quote_for_equal
(
table
,
temp_buff
));
if
(
mysql_query_with_error_report
(
mysql
,
&
result
,
query_buff
))
{
if
(
path
)
...
...
@@ -3388,8 +3411,10 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
while
((
row
=
mysql_fetch_row
(
result
)))
{
if
(
str
len
(
row
[
SHOW_EXTRA
])
&&
strstr
(
row
[
SHOW_EXTRA
],
"INVISIBLE"
))
if
(
str
str
(
row
[
1
],
"INVISIBLE"
))
complete_insert
=
1
;
if
(
vers_hidden
&&
row
[
2
])
vers_hidden
=
strcmp
(
row
[
2
],
"ROW START"
);
if
(
init
)
{
dynstr_append_checked
(
&
select_field_names
,
", "
);
...
...
@@ -3398,11 +3423,18 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
}
init
=
1
;
dynstr_append_checked
(
&
select_field_names
,
quote_name
(
row
[
SHOW_FIELDNAME
],
name_buff
,
0
));
quote_name
(
row
[
0
],
name_buff
,
0
));
if
(
opt_header
)
dynstr_append_checked
(
&
select_field_names_for_header
,
quote_for_equal
(
row
[
SHOW_FIELDNAME
],
name_buff
));
quote_for_equal
(
row
[
0
],
name_buff
));
}
if
(
vers_hidden
)
{
complete_insert
=
1
;
dynstr_append_checked
(
&
select_field_names
,
", row_start, row_end"
);
}
/*
If write_data is true, then we build up insert statements for
the table's data. Note: in subsequent lines of code, this test
...
...
@@ -3433,7 +3465,7 @@ static uint get_table_structure(const char *table, const char *db, char *table_t
if
(
complete_insert
)
dynstr_append_checked
(
&
insert_pat
,
select_field_names
.
str
);
num_fields
=
mysql_num_rows
(
result
);
num_fields
=
mysql_num_rows
(
result
)
+
(
vers_hidden
?
2
:
0
)
;
mysql_free_result
(
result
);
}
else
...
...
@@ -4033,10 +4065,15 @@ static char *alloc_query_str(size_t size)
static
void
vers_append_system_time
(
DYNAMIC_STRING
*
query_string
)
{
DBUG_ASSERT
(
opt_asof_timestamp
);
dynstr_append_checked
(
query_string
,
" FOR SYSTEM_TIME AS OF TIMESTAMP '"
);
dynstr_append_checked
(
query_string
,
opt_asof_timestamp
);
dynstr_append_checked
(
query_string
,
"'"
);
if
(
opt_dump_history
)
dynstr_append_checked
(
query_string
,
" FOR SYSTEM_TIME ALL"
);
else
{
DBUG_ASSERT
(
opt_asof_timestamp
);
dynstr_append_checked
(
query_string
,
" FOR SYSTEM_TIME AS OF TIMESTAMP '"
);
dynstr_append_checked
(
query_string
,
opt_asof_timestamp
);
dynstr_append_checked
(
query_string
,
"'"
);
}
}
...
...
@@ -4282,6 +4319,11 @@ static void dump_table(const char *table, const char *db, const uchar *hash_key,
goto
err
;
}
if
(
versioned
&&
!
opt_xml
&&
opt_dump_history
)
{
fprintf
(
md_result_file
,
"/*!101100 SET system_versioning_insert_history=1 */;
\n
"
);
check_io
(
md_result_file
);
}
if
(
opt_lock
)
{
fprintf
(
md_result_file
,
"LOCK TABLES %s WRITE;
\n
"
,
opt_quoted_table
);
...
...
@@ -4579,6 +4621,11 @@ static void dump_table(const char *table, const char *db, const uchar *hash_key,
fprintf
(
md_result_file
,
"commit;
\n
"
);
check_io
(
md_result_file
);
}
if
(
versioned
&&
!
opt_xml
&&
opt_dump_history
)
{
fprintf
(
md_result_file
,
"/*!101100 SET system_versioning_insert_history=1 */;
\n
"
);
check_io
(
md_result_file
);
}
mysql_free_result
(
res
);
}
dynstr_free
(
&
query_string
);
...
...
mysql-test/suite/versioning/r/data.result
View file @
d249761a
...
...
@@ -57,3 +57,129 @@ INSERT INTO `t1` VALUES
#MYSQL_DUMP --compact --as-of="1990-08-04 00:00' where 'abc" test 2>&1
mysqldump: Incorrect DATETIME value: '1990-08-04 00:00' where 'abc'
drop tables t1;
#
# MDEV-16029 mysqldump: dump and restore historical data
#
create or replace table t1 (x int) with system versioning;
set timestamp=unix_timestamp('2010-10-10 10:10:10.101010');
insert into t1 values (1), (2);
set timestamp=unix_timestamp('2011-11-11 11:11:11.111111');
delete from t1 where x = 1;
set timestamp=default;
select row_start, row_end into @s1, @e1 from t1 for system_time all where x = 1;
select row_start, row_end into @s2, @e2 from t1 for system_time all where x = 2;
create or replace table t2 (
x int,
row_start timestamp(6) as row start invisible,
row_end timestamp(6) as row end invisible,
period for system_time (row_start, row_end))
with system versioning;
create or replace function check_fields(x int, row_start timestamp(6), row_end timestamp(6))
returns char(50) deterministic
return if (x = 1,
if (row_start = @s1 and row_end = @e1, '[CORRECT]', '[WRONG]'),
if (x = 2 and row_start = @s2 and row_end = @e2, '[CORRECT]', '[WRONG]'));
set @@system_versioning_insert_history= 1;
insert into t2 (x, row_start, row_end) select x, row_start, row_end from t1 for system_time all;
set @@system_versioning_insert_history= 0;
# t2 has the same data as t1
select x, check_fields(x, row_start, row_end) from t2 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t1` (
`x` int(11) DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci WITH SYSTEM VERSIONING;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!101100 SET system_versioning_insert_history=1 */;
INSERT INTO `t1` (`x`, row_start, row_end) VALUES (1,'2010-10-10 10:10:10.101010','2011-11-11 11:11:11.111111'),
(2,'2010-10-10 10:10:10.101010','2038-01-19 03:14:07.999999');
/*!101100 SET system_versioning_insert_history=1 */;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `t2` (
`x` int(11) DEFAULT NULL,
`row_start` timestamp(6) GENERATED ALWAYS AS ROW START INVISIBLE,
`row_end` timestamp(6) GENERATED ALWAYS AS ROW END INVISIBLE,
PERIOD FOR SYSTEM_TIME (`row_start`, `row_end`)
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci WITH SYSTEM VERSIONING;
/*!40101 SET character_set_client = @saved_cs_client */;
/*!101100 SET system_versioning_insert_history=1 */;
INSERT INTO `t2` (`x`, `row_start`, `row_end`) VALUES (1,'2010-10-10 10:10:10.101010','2011-11-11 11:11:11.111111'),
(2,'2010-10-10 10:10:10.101010','2038-01-19 03:14:07.999999');
/*!101100 SET system_versioning_insert_history=1 */;
mysqldump: --dump-history can't be used with --as-of.
mysqldump: --dump-history can't be used with --replace.
mysqldump: --xml can't be used with --dump-history.
# SQL dump with/without history
## With history
drop tables t1, t2;
select x, check_fields(x, row_start, row_end) from t1 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
select x, check_fields(x, row_start, row_end) from t2 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
## Without history
drop tables t1, t2;
select x, check_row_ts(row_start, row_end) from t1 for system_time all order by x;
x check_row_ts(row_start, row_end)
2 CURRENT ROW
select x, check_row_ts(row_start, row_end) from t2 for system_time all order by x;
x check_row_ts(row_start, row_end)
2 CURRENT ROW
## History and --no-create-info --skip-comments
create or replace table t1 (x int) with system versioning;
delete from t2;
delete history from t2;
select x, check_fields(x, row_start, row_end) from t1 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
select x, check_fields(x, row_start, row_end) from t2 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
## compact
select x, check_fields(x, row_start, row_end) from t1 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
select x, check_fields(x, row_start, row_end) from t2 for system_time all order by x;
x check_fields(x, row_start, row_end)
1 [CORRECT]
2 [CORRECT]
create or replace table t1 (x int) with system versioning;
# --tab with history
drop tables t1, t2;
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`x` int(11) DEFAULT NULL
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci WITH SYSTEM VERSIONING
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`x` int(11) DEFAULT NULL,
`row_start` timestamp(6) GENERATED ALWAYS AS ROW START INVISIBLE,
`row_end` timestamp(6) GENERATED ALWAYS AS ROW END INVISIBLE,
PERIOD FOR SYSTEM_TIME (`row_start`, `row_end`)
) ENGINE=MyISAM DEFAULT CHARSET=latin1 COLLATE=latin1_swedish_ci WITH SYSTEM VERSIONING
set @@system_versioning_insert_history= 1;
load data infile 'tmp/t1.txt' into table t1 (x, row_start, row_end);
load data infile 'tmp/t2.txt' into table t2 (x, row_start, row_end);
set @@system_versioning_insert_history= 0;
select *, check_row_ts(row_start, row_end) from t1 for system_time all;
x check_row_ts(row_start, row_end)
1 HISTORICAL ROW
2 CURRENT ROW
select *, check_row_ts(row_start, row_end) from t2 for system_time all;
x check_row_ts(row_start, row_end)
1 HISTORICAL ROW
2 CURRENT ROW
drop tables t1, t2;
drop function check_fields;
mysql-test/suite/versioning/t/data.test
View file @
d249761a
...
...
@@ -29,4 +29,122 @@ set timestamp=default;
drop
tables
t1
;
--
echo
#
--
echo
# MDEV-16029 mysqldump: dump and restore historical data
--
echo
#
create
or
replace
table
t1
(
x
int
)
with
system
versioning
;
set
timestamp
=
unix_timestamp
(
'2010-10-10 10:10:10.101010'
);
insert
into
t1
values
(
1
),
(
2
);
set
timestamp
=
unix_timestamp
(
'2011-11-11 11:11:11.111111'
);
delete
from
t1
where
x
=
1
;
set
timestamp
=
default
;
select
row_start
,
row_end
into
@
s1
,
@
e1
from
t1
for
system_time
all
where
x
=
1
;
select
row_start
,
row_end
into
@
s2
,
@
e2
from
t1
for
system_time
all
where
x
=
2
;
create
or
replace
table
t2
(
x
int
,
row_start
timestamp
(
6
)
as
row
start
invisible
,
row_end
timestamp
(
6
)
as
row
end
invisible
,
period
for
system_time
(
row_start
,
row_end
))
with
system
versioning
;
eval
create
or
replace
function
check_fields
(
x
int
,
row_start
timestamp
(
6
),
row_end
timestamp
(
6
))
returns
char
(
50
)
deterministic
return
if
(
x
=
1
,
if
(
row_start
=
@
s1
and
row_end
=
@
e1
,
'[CORRECT]'
,
'[WRONG]'
),
if
(
x
=
2
and
row_start
=
@
s2
and
row_end
=
@
e2
,
'[CORRECT]'
,
'[WRONG]'
));
set
@@
system_versioning_insert_history
=
1
;
insert
into
t2
(
x
,
row_start
,
row_end
)
select
x
,
row_start
,
row_end
from
t1
for
system_time
all
;
set
@@
system_versioning_insert_history
=
0
;
--
echo
# t2 has the same data as t1
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t2
for
system_time
all
order
by
x
;
--
let
TMP
=
$MYSQLTEST_VARDIR
/
tmp
--
exec
$MYSQL_DUMP
--
dump
-
history
--
databases
test
>
$TMP
/
dump_history
.
sql
--
exec
$MYSQL_DUMP
--
databases
test
>
$TMP
/
dump_no_history
.
sql
--
exec
$MYSQL_DUMP
--
dump
-
history
--
no
-
create
-
info
--
skip
-
comments
--
databases
test
>
$TMP
/
dump_only_data
.
sql
--
exec
$MYSQL_DUMP
--
dump
-
history
--
compact
test
2
>&
1
>
$TMP
/
dump_history_compact
.
sql
--
cat_file
$TMP
/
dump_history_compact
.
sql
--
replace_result
mysqldump
.
exe
mysqldump
--
error
1
--
exec
$MYSQL_DUMP
--
dump
-
history
--
as
-
of
=
"1990-01-02 00:00"
test
2
>&
1
--
replace_result
mysqldump
.
exe
mysqldump
--
error
1
--
exec
$MYSQL_DUMP
--
dump
-
history
--
replace
test
2
>&
1
--
replace_result
mysqldump
.
exe
mysqldump
--
error
1
--
exec
$MYSQL_DUMP
--
dump
-
history
--
xml
test
2
>&
1
--
exec
$MYSQL_DUMP
--
dump
-
history
--
tab
=
$TMP
test
--
echo
# SQL dump with/without history
--
echo
## With history
drop
tables
t1
,
t2
;
--
exec
$MYSQL
test
<
$TMP
/
dump_history
.
sql
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t1
for
system_time
all
order
by
x
;
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t2
for
system_time
all
order
by
x
;
--
echo
## Without history
drop
tables
t1
,
t2
;
--
exec
$MYSQL
test
<
$TMP
/
dump_no_history
.
sql
select
x
,
check_row_ts
(
row_start
,
row_end
)
from
t1
for
system_time
all
order
by
x
;
select
x
,
check_row_ts
(
row_start
,
row_end
)
from
t2
for
system_time
all
order
by
x
;
--
echo
## History and --no-create-info --skip-comments
create
or
replace
table
t1
(
x
int
)
with
system
versioning
;
delete
from
t2
;
delete
history
from
t2
;
--
exec
$MYSQL
test
<
$TMP
/
dump_only_data
.
sql
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t1
for
system_time
all
order
by
x
;
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t2
for
system_time
all
order
by
x
;
--
echo
## compact
--
exec
$MYSQL
test
<
$TMP
/
dump_history
.
sql
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t1
for
system_time
all
order
by
x
;
select
x
,
check_fields
(
x
,
row_start
,
row_end
)
from
t2
for
system_time
all
order
by
x
;
create
or
replace
table
t1
(
x
int
)
with
system
versioning
;
# TODO: MDEV-16766 mysqldump: dump history in XML
if
(
0
)
{
--
echo
# XML with history
drop
table
t1
;
create
or
replace
table
t1
(
x
int
)
with
system
versioning
;
delete
from
t2
;
delete
history
from
t2
;
set
@@
system_versioning_insert_history
=
1
;
--
replace_result
$TMP
TMP
eval
load
xml
infile
'$TMP/dump_history.xml'
into
table
t1
;
--
exec
cp
$TMP
/
dump_history
.
xml
/
tmp
set
@@
system_versioning_insert_history
=
0
;
--
echo
## History is now loaded as current data (TODO)
select
*
,
check_row_ts
(
row_start
,
row_end
)
from
t1
for
system_time
all
;
# TODO: check mysqlimport
# --exec $MYSQL_IMPORT test $TMP/dump_history.xml
}
--
echo
# --tab with history
drop
tables
t1
,
t2
;
--
exec
$MYSQL
test
<
$TMP
/
t1
.
sql
--
exec
$MYSQL
test
<
$TMP
/
t2
.
sql
show
create
table
t1
;
show
create
table
t2
;
set
@@
system_versioning_insert_history
=
1
;
--
replace_result
$TMP
tmp
eval
load
data
infile
'$TMP/t1.txt'
into
table
t1
(
x
,
row_start
,
row_end
);
--
replace_result
$TMP
tmp
eval
load
data
infile
'$TMP/t2.txt'
into
table
t2
(
x
,
row_start
,
row_end
);
set
@@
system_versioning_insert_history
=
0
;
select
*
,
check_row_ts
(
row_start
,
row_end
)
from
t1
for
system_time
all
;
select
*
,
check_row_ts
(
row_start
,
row_end
)
from
t2
for
system_time
all
;
# Cleanup
--
remove_files_wildcard
$TMP
*.
sql
--
remove_files_wildcard
$TMP
*.
txt
--
remove_files_wildcard
$TMP
*.
xml
drop
tables
t1
,
t2
;
drop
function
check_fields
;
--
source
suite
/
versioning
/
common_finish
.
inc
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment