Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Situation Awareness
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
SoftWare Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive

Migrating Data to RDS for MySQL Using mysqldump

Updated on 2025-02-13 GMT+08:00

Preparing for Data Migration

You can access RDS DB instances through an EIP or through an ECS.

  1. Prepare an ECS for accessing DB instances in the same VPC or prepare a device for accessing RDS through an EIP.
    • To connect to a DB instance through an ECS, you need to create an ECS first.
    • To connect to a DB instance through an EIP, you must:
      1. Bind an EIP to the DB instance. For details, see Binding an EIP.
      2. Ensure that the local device can access the EIP.
  2. Install a MySQL client on the prepared ECS or device.

    For details, see How Can I Install the MySQL Client?

    NOTE:

    The MySQL client version must be the same as the DB engine version of your RDS for MySQL instance. A MySQL database or client will provide mysqldump and mysql.

    After data is migrated to RDS, you may need to change the IP address. For details, see Changing a Floating IP Address.

    RDS system databases mysql and sys cannot be imported from one RDS for MySQL instance to another.

Exporting Data

Before migrating a database to RDS, its data needs to be exported.

NOTICE:
  • The export tool must match the DB engine version.
  • Database migration is performed offline. Before the migration, you have to stop all applications using the source database.
  • Take care when exporting or importing data. Improper operations can cause instance or service exceptions.
  1. Log in to the source database.
  2. Use the mysqldump tool to export the table structure to an SQL file.

    NOTICE:

    The mysql database is required for RDS management. When exporting the table structure, do not specify --all-database. Otherwise, a database fault will occur.

    mysqldump--databases<DB_NAME>--single-transaction --order-by-primary --hex-blob --no-data --routines --events --set-gtid-purged=OFF-u <DB_USER>-p -h<DB_ADDRESS>-P <DB_PORT>|sed -e 's/DEFINER[ ]*=[ ]*[^*]*\*/\*/' -e 's/DEFINER[ ]*=.*FUNCTION/FUNCTION/' -e 's/DEFINER[ ]*=.*PROCEDURE/PROCEDURE/' -e 's/DEFINER[ ]*=.*TRIGGER/TRIGGER/' -e 's/DEFINER[ ]*=.*EVENT/EVENT/' ><BACKUP_FILE>

    • DB_NAME indicates the name of the database to be migrated.
    • DB_USER indicates the database username.
    • DB_ADDRESS indicates the database address.
    • DB_PORT indicates the database port.
    • BACKUP_FILE indicates the name of the file to which the data will be exported.

    Enter the database password when prompted.

    Example:

    mysqldump --databases rdsdb --single-transaction --order-by-primary --hex-blob --no-data --routines --events --set-gtid-purged=OFF -u root -p -h 192.168.151.18 -P 3306 |sed -e 's/DEFINER[ ]*=[ ]*[^*]*\*/\*/' -e 's/DEFINER[ ]*=.*FUNCTION/FUNCTION/' -e 's/DEFINER[ ]*=.*PROCEDURE/PROCEDURE/' -e 's/DEFINER[ ]*=.*TRIGGER/TRIGGER/' -e 's/DEFINER[ ]*=.*EVENT/EVENT/' > dump-defs.sql

    Enter password:

    NOTE:

    If you use mysqldump with a version earlier than 5.6, remove --set-gtid-purged=OFF before running this command.

    After this command is executed, a dump-defs.sql file will be generated as follows:

    [rds@localhost ~]$ ll dump-defs.sql
    -rw-r-----. 1 rds rds 2714 Sep 21 08:23 dump-defs.sql

  3. Use the mysqldump tool to export data to an SQL file.

    NOTICE:

    The mysql database is required for RDS management. When exporting data, do not specify --all-database. Otherwise, a database fault will occur.

    mysqldump --databases<DB_NAME>--single-transaction --hex-blob --set-gtid-purged=OFF --no-create-info --skip-triggers-u<DB_USER>-p-h<DB_ADDRESS>-P<DB_PORT>-r<BACKUP_FILE>

    For details on the parameters in the preceding command, see 2.

    Enter the database password when prompted.

    Example:

    mysqldump --databases rdsdb --single-transaction --hex-blob --set-gtid-purged=OFF --no-create-info --skip-triggers -u root -p -h 192.168.151.18 -P 3306 -r dump-data.sql

    NOTE:

    If you use mysqldump with a version earlier than 5.6, remove --set-gtid-purged=OFF before running this command.

    After this command is executed, a dump-data.sql file will be generated as follows:

    [rds@localhost ~]$ ll dump-data.sql
    -rw-r-----. 1 rds rds 2714 Sep 21 08:23 dump-data.sql

Importing Data

You can connect your client to RDS and import exported SQL files into RDS.

NOTICE:

If the source database calls triggers, stored procedures, functions, or events, you must set log_bin_trust_function_creators to ON on the destination database before importing data.

  1. Log in to the ECS or the device that can access the RDS DB instance.
  2. Connect to the RDS DB instance through a client.
  3. Import the table structure into RDS.

    # mysql -f -h<RDS_ADDRESS>-P<DB_PORT>-uroot-p < <BACKUP_DIR>/dump-defs.sql

    • RDS_ADDRESS indicates the IP address of the RDS DB instance.
    • DB_PORT indicates the RDS DB instance port.
    • BACKUP_DIR indicates the directory where dump-defs.sql is stored.

    Example:

    # mysql -f -h 172.16.66.198 -P 3306 -u root -p < dump-defs.sql

    Enter password:

    NOTE:

    If you intend to import SQL statements of a table to RDS, specify a database in the command. Otherwise, the error message "No database selected" may be displayed. For example, if you intend to import SQL statements of a table to database mydb, run the following command:

    # mysql -f -h 172.16.66.198 -P 3306 -u root -p mydb < dump-defs.sql

    Enter password:

  4. Import data into RDS.

    # mysql -f -h<RDS_ADDRESS>-P<DB_PORT>-uroot-p< <BACKUP_DIR>/dump-data.sql

    • RDS_ADDRESS indicates the IP address of the RDS DB instance.
    • DB_PORT indicates the RDS DB instance port.
    • BACKUP_DIR indicates the directory where dump-data.sql is stored.

    Example:

    # mysql -f -h 172.16.66.198 -P 3306 -u root -p < dump-data.sql

    Enter password:

    NOTE:

    If you intend to import SQL statements of a table to RDS, specify a database in the command. Otherwise, the error message "No database selected" may be displayed. For example, if you intend to import SQL statements of a table to database mydb, run the following command:

    # mysql -f -h 172.16.66.198 -P 3306 -u root -p mydb < dump-defs.sql

    Enter password:

  5. View the import result.

    mysql> show databases;

    The following result indicates that database rdsdb has been imported.

    mysql> show databases;
    +--------------------+
    | Database           |
    +--------------------+
    | information_schema |
    | rdsdb              |
    | mysql              |
    | performance_schema |
    +--------------------+
    4 rows in set (0.00 sec)

We use cookies to improve our site and your experience. By continuing to browse our site you accept our cookie policy. Find out more

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback