Tips and Tricks in using mysqldump and mysql restore to Azure Database for MySQL
Published Oct 16 2019 04:59 PM 11.4K Views
Microsoft

While importing data into Azure Database for MySQL, errors may occur. This blog will walk through common issues that you may face and how to resolve it.

  1. Access denied; you need (at least one of) the SUPER privilege(s) for this operation:

Error
ERROR 1227 (42000) at line 101: Access denied; you need (at least one of) the SUPER privilege(s) for this operation
Operation failed with exitcode 1

 

Issue
Importing a dump file that contains definers will result in the above error. As all of us know, only super users can perform and create definers in other schemas. Azure Database for MySQL is a managed PaaS solution and SUPER privileges is restricted.

Solution
Either replace the definers with the name of the admin user that is running the import process or remove it.

The admin user can grant privileges to create or execute procedures by running GRANT command as in the following examples:

GRANT CREATE ROUTINE ON mydb.* TO 'someuser'@'somehost';
GRANT EXECUTE ON PROCEDURE mydb.myproc TO 'someuser'@'somehost';

 

Example:

Before:

DELIMITER ;;

/*!50003 CREATE*/ /*!50017 DEFINER=`root`@`127.0.0.1`*/ /*!50003 ……

DELIMITER ;

After:

DELIMITER ;;

/*!50003 CREATE*/ /*!50017 DEFINER=`AdminUserName`@`ServerName`*/ /*!50003 ……

DELIMITER ;

 

  1. importing triggers while binary logging is enabled:

Error
ERROR 1419 (HY000) at line 101: You do not have the SUPER privilege and binary logging is enabled (you *might* want to use the less safe log_bin_trust_function_creators variable)
Operation failed with exitcode 1

 

Issue
Importing a dump file that contains triggers will result in the above error if binary logging is enabled.

Solution
To mitigate the issue, you need to enable the parameter “log_bin_trust_function_creators” from Azure portal parameters blade.

 

  1. storage engine not supported:

Error
ERROR 1030 (HY000) at line 114: Got error 1 from storage engine
Operation failed with exitcode 1


Issue
You will see the above error when you use a storage engine other than InnoDB and MEMORY. Read more on support engine types here: Storage engine support

 

Solution
Before the import process make sure that you are using a supported engine type; InnoDB and MEMORY are the only supported engine types in Azure Database for MySQL.
If you dumped the data from a different engine type, edit the file and replace the storage engine. For example, exchange ENGINE=MYISAM with ENGINE=InnoDB.

Note: You can always dump the schema first using the command: mysqldump --no-data option, and then dump the data using option: mysqldump --no-create-info option

Example :

Before:

CREATE TABLE `MyTable` (

  `ID` bigint(20) NOT NULL AUTO_INCREMENT,

  `DeviceID` varchar(50) NOT NULL,

  PRIMARY KEY (`ID`)

) ENGINE=MyISAM DEFAULT CHARSET=utf8;

 

After:

CREATE TABLE `MyTable` (

  `ID` bigint(20) NOT NULL AUTO_INCREMENT,

  `DeviceID` varchar(50) NOT NULL,

  PRIMARY KEY (`ID`)

) ENGINE=InnoDB DEFAULT CHARSET=utf8;

 

  1. InnoDB storage engine row format:

Error
ERROR 1031 (HY000) at line 114: Table storage engine for 'mytable' doesn't have this option
Operation failed with exitcode 1

 

Issue
In Azure Database for MySQL, four row format options are supported: DYNAMIC, COMPACT and REDUNDANT, the COMPRESSED row format is supported under certain conditions.

 

Solution

We support compressed format on General Purpose or Memory Optimized. Customer needs to enable the parameter “innodb_file_per_table” from Azure portal parameters blade, and key_block_size must be 8 or greater than 8. In default, key_block_size is 8.

 

Please visit the Performance considerations guide for best practices while migrating into Azure Database for MySQL.

 

Thank You !

2 Comments
Version history
Last update:
‎Oct 16 2019 04:59 PM
Updated by: