AnalyticDB for MySQL allows you to use external tables to import and export data. This topic describes how to use external tables of AnalyticDB for MySQL to export data to a self-managed MySQL database.

Prerequisites

  • A self-managed MySQL database is created and hosted on an ECS instance.
  • The ECS instance and the AnalyticDB for MySQL cluster are deployed in the same virtual private cloud (VPC).
  • A self-managed MySQL database is created and hosted on an ECS instance. Test data is prepared.
    In this example, the test_adb self-managed MySQL database hosted on the ECS instance is used as the destination database. A destination table named courses is created in the database. The table is used to store data that is exported from the AnalyticDB for MySQL cluster. The following statement is used to create the destination table:
    CREATE TABLE courses (
        id bigint NOT NULL,
        name varchar(32) NOT NULL,
        grade varchar(32) NOT NULL,
        submission_date  timestamp NOT NULL,
        PRIMARY KEY (id)
    );
  • If the AnalyticDB for MySQL cluster is in elastic mode, you must turn on ENI in the Network Information section of the Cluster Information page. Enable ENI

Procedure

  1. Connect to the AnalyticDB for MySQL cluster. For more information, see Connect to an AnalyticDB for MySQL cluster.
  2. Create a source database. For more information, see Create a database.

    In this example, a database named adb_demo is used as the source database in the AnalyticDB for MySQL cluster.

  3. Create a source table and insert data into the source table.

    Execute the following statement to create a source table named courses in the adb_demo source database. Then, export data in the source table to the courses table in the test_adb self-managed MySQL database.

    CREATE TABLE courses (
    id bigint AUTO_INCREMENT,
    name varchar NOT NULL,
    grade varchar DEFAULT '1st Grade',
    submission_date timestamp
    ) DISTRIBUTE BY HASH(id);
    Execute the following statement to insert a row of data into the courses source table:
    INSERT INTO courses (name,submission_date) VALUES("Jams",NOW());
  4. Create an external mapping table.
    Execute the following statement to create an external mapping table named courses_external_table in the adb_demo source database:
     CREATE TABLE IF NOT EXISTS courses_external_table(
     id bigint NOT NULL,
     name varchar(32) NOT NULL,
     grade varchar(32) NOT NULL,
     submission_date  timestamp NOT NULL,
     PRIMARY KEY (id)
     )
    ENGINE='mysql'  
    TABLE_PROPERTIES='{  
    "url":"jdbc:mysql://mysql-vpc-address:3306/test_adb",  
    "tablename":"courses",  
    "username":"mysql-user-name",  
    "password":"mysql-user-password"
    }';
    Parameter Description
    ENGINE='mysql' The storage engine used for the external table. In this example, MySQL is used.
    TABLE_PROPERTIES The connection information used by the AnalyticDB for MySQL cluster to access the data in the self-managed MySQL database hosted on the ECS instance.
    url The Primary Private IP Address value or the VPC endpoint of the ECS instance, and the name of the destination database. In this example, the name of the destination database is test_adb. Perform the following steps to view the VPC endpoint of the ECS instance:
    1. Log on to the ECS console and find the ECS instance.
    2. In the Network Information section on the Instance Details tab, view the Primary Private IP Address value of the ECS instance.

    The endpoint is in the "jdbc:mysql://mysql-vpc-address:3306/ecs-database-name" format.

    Example: jdbc:mysql://192.168.128.***:3306/test_adb

    tablename The name of the destination table in the self-managed MySQL database hosted on the ECS instance. In this example, courses is used.
    username The account used to connect to the self-managed MySQL database hosted on the ECS instance.
    password The password of the preceding account.
  5. Import data from the AnalyticDB for MySQL cluster to the self-managed MySQL database hosted on the ECS instance.
    Execute the following statement:
    REPLACE INTO courses_external_table
    SELECT * FROM courses;

What to do next

After the data is exported, you can log on to the test_adb self-managed MySQL database. Then, execute the following statement to check whether the data is imported from the source table to the courses destination table:
SELECT * FROM courses LIMIT 100;