This section covers operational guides for managing a Federated Spider topology, including migrating tables and performing backup and restore.
A guide on how to migrate tables from a standard MariaDB deployment to a Federated Spider topology, distributing data across multiple backend nodes.
The Federated MariaDB Enterprise Spider topology can be used to migrate tables from one MariaDB Enterprise Server node to another MariaDB Enterprise Server node:
The MariaDB Enterprise Server node with the source table is configured as a Data Node.
The MariaDB Enterprise Server node with the destination table is configured as a Spider Node.
The Data Table is the source table on the Data Node.
A Spider Table is created on the Spider Node that references the Data Table on the Data Node.
On the Spider node, the Data Table's data is migrated to the destination table by querying the Spider Table like the following:
Follow the steps below to migrate tables using the Federated MariaDB Enterprise Spider topology.
Before you can migrate tables, the Federated MariaDB Enterprise Spider topology must be deployed.
For additional information, see "".
A local copy of the table must be created. This new table will contain the migrated data.
On the Spider Node*, create a local copy of each table that is being migrated:
The table data can be migrated to the local table using the Spider Tables.
On the Spider Node*, migrate the table data to the local copy of the table using the statement:
On the Spider Node, read from the local copy of the table using a statement to confirm that the data has been migrated:
This page is: Copyright © 2025 MariaDB. All rights reserved.
INSERT INTO innodb_tab
SELECT * FROM spider_tab;CREATE DATABASE hq_sales;
CREATE SEQUENCE hq_sales.invoice_seq;
CREATE TABLE hq_sales.invoices (
branch_id INT NOT NULL DEFAULT (1) CHECK (branch_id=1),
invoice_id INT NOT NULL DEFAULT (NEXT VALUE FOR migrated_hq_sales.invoice_seq),
customer_id INT,
invoice_date DATETIME(6),
invoice_total DECIMAL(13, 2),
payment_method ENUM('NONE', 'CASH', 'WIRE_TRANSFER', 'CREDIT_CARD', 'GIFT_CARD'),
PRIMARY KEY(branch_id, invoice_id)
) ENGINE=InnoDB;INSERT INTO hq_sales.invoices
SELECT * FROM spider_hq_sales.invoices;SELECT * FROM hq_sales.invoices;+-----------+------------+-------------+----------------------------+---------------+----------------+
| branch_id | invoice_id | customer_id | invoice_date | invoice_total | payment_method |
+-----------+------------+-------------+----------------------------+---------------+----------------+
| 1 | 1 | 1 | 2020-05-10 12:35:10.000000 | 1087.23 | CREDIT_CARD |
| 1 | 2 | 2 | 2020-05-10 14:17:32.000000 | 1508.57 | WIRE_TRANSFER |
| 1 | 3 | 3 | 2020-05-10 14:25:16.000000 | 227.15 | CASH |
+-----------+------------+-------------+----------------------------+---------------+----------------+An overview of the federated topology for Spider, where a single Spider node aggregates data from multiple remote data nodes, acting as a unified access point.
Choose an operation for the Sharded MariaDB Enterprise Spider topology:
How to create a new backup or restore an existing backup.
The character set or collation for the Spider Table can be updated or modified using the statement.
On the Spider Node, alter the Spider Table's character set and collation:
If the new character set and collation are not compatible with the character set and collation used by the Data Table, you must also alter the character set and collation for the Data Table on the Data Node.
In a Federated MariaDB Enterprise Spider topology, the connection options for a Data Node can be updated using the statement.
On the Spider Node*, alter the table's connection details:
How to update the character set or collation.
How to update the character set or collation.
How to update the connection options for a Data Node.
Procedures for performing consistent backups and restores in a federated Spider topology using MariaDB Backup and MariaDB Dump, ensuring data synchronization.
ALTER TABLE spider_hq_sales.invoices
DEFAULT CHARACTER SET 'utf8mb4'
DEFAULT COLLATE 'utf8mb4_general_ci';ALTER TABLE spider_hq_sales.invoices
COMMENT = 'server "new_hq_server", table "invoices"'MariaDB Backup can be used to perform backup operations on Spider deployments.
MariaDB Backup can be used to create a physical backup of a Federated MariaDB Enterprise Spider topology. MariaDB Backup must be used to backup the Spider Node and the Data Node. The Spider Node and Data Node must be locked to guarantee that the backups of the Spider Node and Data Node are consistent.
The backup of the Spider Node contains:
Physical backup for Spider Tables
Physical backup for tables that use InnoDB, Aria, MyISAM, and MyRocks
Physical backup for any other database objects on the Spider Node
The backup of the Data Node contains:
Physical backup for Data Tables
Physical backup for tables that use InnoDB, Aria, MyISAM, and MyRocks
Physical backup for any other database objects on the Data Node
The following procedure shows how to take a consistent backup of a Spider Node and a Data Node deployed in a Spider Federated MariaDB Enterprise Spider topology.
On the Spider Node and on the Data Node, create a user account to perform the backup using the CREATE USER and GRANT statements:
On the Data Node, grant the user account Spider uses to operate on the Data Node sufficient privileges to lock the Data Tables using the GRANT statement.
For example, on the hq_server Data Node:
On the Spider Node, acquire a read lock on Spider Tables using the LOCK TABLES statement:
Keep this session open during the rest of the procedure.
The read lock will propagate to the Data Tables on the Data Node. The read locks will prevent the Data Tables from changing during the backup, so the backups of the Spider Node and the Data Node are consistent.
On the Data Node, perform the backup using MariaDB Backup:
When the Data Node backup is complete, perform the backup on the Spider Node using MariaDB Backup:
When the Spider Node backup is complete, release the table locks in your original session using the UNLOCK TABLES statement:
On the Spider Node and the Data Node, prepare each of the backups using MariaDB Backup:
The Spider Node and the Data Node now have a complete backup of the data directory. Backups should be tested to confirm they are complete and consistent.
MariaDB Backup can restore a Federated MariaDB Enterprise Spider topology from a backup taken with MariaDB Backup.
On the Spider Node and on the Data Node, stop the MariaDB Server process:
On the Spider Node and on the Data Node, empty the data directory:
On the Spider Node and on the Data Node, restore the backup for that server using MariaDB Backup:
On the Spider Node and on the Data Node, confirm that the restored files are owned by the user that owns the MariaDB Server process:
On the Spider Node and on the Data Node, start the MariaDB Server process:
On the Spider Node, query a Spider Table to test it:
MariaDB Dump generates backup files containing the SQL statements necessary to recreate the database. MariaDB Dump is included with MariaDB Enterprise Server and can be used to backup databases in Spider deployments. The MariaDB Client can then be used to restore databases from a MariaDB Dump backup.
MariaDB Dump can be used to create a logical backup of a Federated MariaDB Enterprise Spider topology. MariaDB Dump must be used to backup the Spider Node and the Data Node. The Spider Node and Data Node must be locked to guarantee that the backups of the Spider Node and Data Node are consistent.
The backup of the Spider Node contains:
Table definitions for Spider Tables
Table definitions for all tables
Table data for tables that use InnoDB, Aria, MyISAM, and MyRocks
Definitions for any other user accounts, privileges, views, and triggers on the Spider Node
The backup of the Data Node contains:
Table definitions for Data Tables
Table definitions for all tables
Table data for tables that use InnoDB, Aria, MyISAM, and MyRocks
Definitions for any other user accounts, privileges, views, and triggers on the Data Node
The following procedure shows how to take a consistent backup of a Spider Node and a Data Node deployed in a Federated MariaDB Enterprise Spider topology.
On the Spider Node and on the Data Node, create a user account to perform the backup using the CREATE USER and GRANT statements:
On the Data Node, grant the user account Spider uses to operate on the Data Node sufficient privileges to lock the Data Tables using the GRANT statement.
For example, on the hq_server Data Node:
On the Spider Node, acquire a read lock on Spider Tables using the LOCK TABLES statement:
Keep this session open during the rest of the procedure.
The read lock will propagate to the Data Tables on the Data Node. The read locks will prevent the Data Tables from receiving any changes during the backup, which ensures the backups of the Spider Node and the Data Node are consistent.
On the Data Node, perform the backup using MariaDB Dump:
When the Data Node has been backed up, perform the backup on the Spider Node using MariaDB Dump:
When the Spider Node backup is complete, release the table locks in your original session using the UNLOCK TABLES statement:
The Spider Node and the Data Node now each have a mariadb_dump.sql backup file. This backup file contains the SQL statements needed to recreate the schema on the Spider Node and the schema and data on the Data Node. Backups should be tested to confirm they are complete and consistent.
MariaDB Client can restore a Federated MariaDB Enterprise Spider topology from a backup taken with MariaDB Dump backup.
Stop all traffic to the Spider Node and the Data Node.
On the Spider Node, restore the backup for that server using MariaDB Client:
On the Data Node, restore the backup for that server using MariaDB Client:
On the Spider Node, query a Spider Table to test it:
This page is: Copyright © 2025 MariaDB. All rights reserved.
CREATE USER 'mariadb-backup'@'localhost'
IDENTIFIED BY 'mb_passwd';
GRANT RELOAD, PROCESS, LOCK TABLES, BINLOG MONITOR
ON *.*
TO 'mariadb-backup'@'localhost';GRANT LOCK TABLES ON hq_sales.* TO 'spider_user'@'192.0.2.2';LOCK TABLES spider_federated_sales.invoices READ;$ sudo mariadb-backup --backup \
--target-dir=/data/backups/full \
--user=mariadb-backup \
--password='mb_passwd'$ sudo mariadb-backup --backup \
--target-dir=/data/backups/full \
--user=mariadb-backup \
--password='mb_passwd'UNLOCK TABLES;$ sudo mariadb-backup --prepare \
--target-dir=/data/backups/full$ sudo systemctl stop mariadb$ sudo rm -fr /var/lib/mysql/*$ sudo mariadb-backup --copy-back \
--target-dir=/data/backups/full$ sudo chown -R mysql:mysql /var/lib/mysql$ sudo systemctl start mariadbSELECT * FROM spider_hq_sales.invoices;+-----------+------------+-------------+----------------------------+---------------+----------------+
| branch_id | invoice_id | customer_id | invoice_date | invoice_total | payment_method |
+-----------+------------+-------------+----------------------------+---------------+----------------+
| 1 | 1 | 1 | 2020-05-10 12:35:10.000000 | 1087.23 | CREDIT_CARD |
| 1 | 2 | 2 | 2020-05-10 14:17:32.000000 | 1508.57 | WIRE_TRANSFER |
| 1 | 3 | 3 | 2020-05-10 14:25:16.000000 | 227.15 | CASH |
+-----------+------------+-------------+----------------------------+---------------+----------------+CREATE USER 'mariadb-dump'@'localhost'
IDENTIFIED BY 'md_passwd';
GRANT SELECT, INSERT, SHOW VIEW, TRIGGER, CREATE, ALTER, EVENT, RELOAD, LOCK TABLES
ON *.*
TO 'mariadb-dump'@'localhost';GRANT LOCK TABLES ON hq_sales.* TO 'spider_user'@'192.0.2.2';LOCK TABLES spider_federated_sales.invoices READ;$ mariadb-dump \
--user=mariadb-dump \
--password='md_passwd' \
--ssl-verify-server-cert \
--ssl-ca ~/mariadb_chain.pem \
--all-databases \
--single-transaction \
--default-character-set=utf8mb4 \
> mariadb_dump.sql$ mariadb-dump \
--user=mariadb-dump \
--password='md_passwd' \
--ssl-verify-server-cert \
--ssl-ca ~/mariadb_chain.pem \
--all-databases \
--single-transaction \
--default-character-set=utf8mb4 \
> mariadb_dump.sqlUNLOCK TABLES;$ mariadb \
--user=mariadb-dump \
--password='md_passwd' \
--ssl-verify-server-cert \
--ssl-ca ~/mariadb_chain.pem \
--default-character-set=utf8mb4 \
< mariadb_dump.sql$ mariadb \
--user=mariadb-dump \
--password='md_passwd' \
--ssl-verify-server-cert \
--ssl-ca ~/mariadb_chain.pem \
--default-character-set=utf8mb4 \
< mariadb_dump.sqlSELECT * FROM spider_hq_sales.invoices;+-----------+------------+-------------+----------------------------+---------------+----------------+
| branch_id | invoice_id | customer_id | invoice_date | invoice_total | payment_method |
+-----------+------------+-------------+----------------------------+---------------+----------------+
| 1 | 1 | 1 | 2020-05-10 12:35:10.000000 | 1087.23 | CREDIT_CARD |
| 1 | 2 | 2 | 2020-05-10 14:17:32.000000 | 1508.57 | WIRE_TRANSFER |
| 1 | 3 | 3 | 2020-05-10 14:25:16.000000 | 227.15 | CASH |
+-----------+------------+-------------+----------------------------+---------------+----------------+This page is: Copyright © 2025 MariaDB. All rights reserved.