Description:
The SQL produced by mysqldump (10.13 @ 5.1.43, Win32) for views is invalid.
It creates a table for the view (also invalid), which is dropped later and replaced by an -invalid- view.
Table and view creation as well as mysqldump return neither warnings nor errors - the problem arises when importing the dump.
Please find attached an abreviated test case withe the generated dump.
Don't get irritated by the long mysqldump command - it's the original I used to dump a complete database with ~70 tables, views, events etc.
How to repeat:
Database:
------------------------------------------------------------
CREATE DATABASE zzz;
USE zzz;
------------------------------------------------------------
Table:
------------------------------------------------------------
CREATE TABLE IF NOT EXISTS `xyz_groups` (
`groupID` SMALLINT(5) UNSIGNED DEFAULT NULL,
`groupname` VARCHAR(60) BINARY NOT NULL,
`username` VARCHAR(60) BINARY NOT NULL,
UNIQUE INDEX `uidx_username` (`username`)
) ENGINE=InnoDB CHARACTER SET=utf8 COLLATE=utf8_bin;
------------------------------------------------------------
View:
------------------------------------------------------------
CREATE VIEW `xyzGroups` AS SELECT `groupID`, `groupname`, GROUP_CONCAT(DISTINCT `username` ORDER BY `username` ASC SEPARATOR ',') FROM `xyz_groups` GROUP BY `groupname`;
------------------------------------------------------------
mysqldump command:
------------------------------------------------------------
mysqldump --add-drop-table --allow-keywords --comments --complete-insert --create-options --disable-keys --events --extended-insert --host=localhost --port=3306 --user=root --password=<password> --quick --quote-names --result-file=xyztest.sql --routines --triggers --databases <database>
------------------------------------------------------------
Produced dump:
------------------------------------------------------------
-- MySQL dump 10.13 Distrib 5.1.43, for Win32 (ia32)
--
-- Host: localhost Database: zzz
-- ------------------------------------------------------
-- Server version 5.1.43-community
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */;
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
/*!40101 SET NAMES utf8 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
--
-- Current Database: `zzz`
--
CREATE DATABASE /*!32312 IF NOT EXISTS*/ `zzz` /*!40100 DEFAULT CHARACTER SET utf8 */;
USE `zzz`;
--
-- Table structure for table `xyz_groups`
--
DROP TABLE IF EXISTS `xyz_groups`;
/*!40101 SET @saved_cs_client = @@character_set_client */;
/*!40101 SET character_set_client = utf8 */;
CREATE TABLE `xyz_groups` (
`groupID` smallint(5) unsigned DEFAULT NULL,
`groupname` varchar(60) COLLATE utf8_bin NOT NULL,
`username` varchar(60) COLLATE utf8_bin NOT NULL,
UNIQUE KEY `uidx_username` (`username`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_bin;
/*!40101 SET character_set_client = @saved_cs_client */;
--
-- Dumping data for table `xyz_groups`
--
LOCK TABLES `xyz_groups` WRITE;
/*!40000 ALTER TABLE `xyz_groups` DISABLE KEYS */;
/*!40000 ALTER TABLE `xyz_groups` ENABLE KEYS */;
UNLOCK TABLES;
--
-- Temporary table structure for view `xyzgroups`
--
DROP TABLE IF EXISTS `xyzgroups`;
/*!50001 DROP VIEW IF EXISTS `xyzgroups`*/;
SET @saved_cs_client = @@character_set_client;
SET character_set_client = utf8;
/*!50001 CREATE TABLE `xyzgroups` (
`groupID` smallint(5) unsigned,
`groupname` varchar(60),
`GROUP_CONCAT(DISTINCT ``username`` ORDER BY ``username`` ASC SEPARAT` varchar(341)
) ENGINE=MyISAM */;
SET character_set_client = @saved_cs_client;
--
-- Dumping events for database 'zzz'
--
--
-- Dumping routines for database 'zzz'
--
--
-- Current Database: `zzz`
--
USE `zzz`;
--
-- Final view structure for view `xyzgroups`
--
/*!50001 DROP TABLE IF EXISTS `xyzgroups`*/;
/*!50001 DROP VIEW IF EXISTS `xyzgroups`*/;
/*!50001 SET @saved_cs_client = @@character_set_client */;
/*!50001 SET @saved_cs_results = @@character_set_results */;
/*!50001 SET @saved_col_connection = @@collation_connection */;
/*!50001 SET character_set_client = utf8 */;
/*!50001 SET character_set_results = utf8 */;
/*!50001 SET collation_connection = utf8_general_ci */;
/*!50001 CREATE ALGORITHM=UNDEFINED */
/*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */
/*!50001 VIEW `xyzgroups` AS select `xyz_groups`.`groupID` AS `groupID`,`xyz_groups`.`groupname` AS `groupname`,group_concat(distinct `xyz_groups`.`username` order by `xyz_groups`.`username` ASC separator ',') AS `GROUP_CONCAT(DISTINCT ``username`` ORDER BY ``username`` ASC SEPARATOR ',')` from `xyz_groups` group by `xyz_groups`.`groupname` */;
/*!50001 SET character_set_client = @saved_cs_client */;
/*!50001 SET character_set_results = @saved_cs_results */;
/*!50001 SET collation_connection = @saved_col_connection */;
/*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */;
/*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
/*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */;
/*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */;
/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */;
/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */;
/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;
/*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */;
-- Dump completed on 2010-02-19 0:23:56
------------------------------------------------------------
Suggested fix:
- Don't create tables for views at all
- Don't use aliases in the generated SQL as the alias for the group_concat is also group_concat
Description: The SQL produced by mysqldump (10.13 @ 5.1.43, Win32) for views is invalid. It creates a table for the view (also invalid), which is dropped later and replaced by an -invalid- view. Table and view creation as well as mysqldump return neither warnings nor errors - the problem arises when importing the dump. Please find attached an abreviated test case withe the generated dump. Don't get irritated by the long mysqldump command - it's the original I used to dump a complete database with ~70 tables, views, events etc. How to repeat: Database: ------------------------------------------------------------ CREATE DATABASE zzz; USE zzz; ------------------------------------------------------------ Table: ------------------------------------------------------------ CREATE TABLE IF NOT EXISTS `xyz_groups` ( `groupID` SMALLINT(5) UNSIGNED DEFAULT NULL, `groupname` VARCHAR(60) BINARY NOT NULL, `username` VARCHAR(60) BINARY NOT NULL, UNIQUE INDEX `uidx_username` (`username`) ) ENGINE=InnoDB CHARACTER SET=utf8 COLLATE=utf8_bin; ------------------------------------------------------------ View: ------------------------------------------------------------ CREATE VIEW `xyzGroups` AS SELECT `groupID`, `groupname`, GROUP_CONCAT(DISTINCT `username` ORDER BY `username` ASC SEPARATOR ',') FROM `xyz_groups` GROUP BY `groupname`; ------------------------------------------------------------ mysqldump command: ------------------------------------------------------------ mysqldump --add-drop-table --allow-keywords --comments --complete-insert --create-options --disable-keys --events --extended-insert --host=localhost --port=3306 --user=root --password=<password> --quick --quote-names --result-file=xyztest.sql --routines --triggers --databases <database> ------------------------------------------------------------ Produced dump: ------------------------------------------------------------ -- MySQL dump 10.13 Distrib 5.1.43, for Win32 (ia32) -- -- Host: localhost Database: zzz -- ------------------------------------------------------ -- Server version 5.1.43-community /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; /*!40101 SET NAMES utf8 */; /*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */; /*!40103 SET TIME_ZONE='+00:00' */; /*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */; /*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */; /*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */; /*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */; -- -- Current Database: `zzz` -- CREATE DATABASE /*!32312 IF NOT EXISTS*/ `zzz` /*!40100 DEFAULT CHARACTER SET utf8 */; USE `zzz`; -- -- Table structure for table `xyz_groups` -- DROP TABLE IF EXISTS `xyz_groups`; /*!40101 SET @saved_cs_client = @@character_set_client */; /*!40101 SET character_set_client = utf8 */; CREATE TABLE `xyz_groups` ( `groupID` smallint(5) unsigned DEFAULT NULL, `groupname` varchar(60) COLLATE utf8_bin NOT NULL, `username` varchar(60) COLLATE utf8_bin NOT NULL, UNIQUE KEY `uidx_username` (`username`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_bin; /*!40101 SET character_set_client = @saved_cs_client */; -- -- Dumping data for table `xyz_groups` -- LOCK TABLES `xyz_groups` WRITE; /*!40000 ALTER TABLE `xyz_groups` DISABLE KEYS */; /*!40000 ALTER TABLE `xyz_groups` ENABLE KEYS */; UNLOCK TABLES; -- -- Temporary table structure for view `xyzgroups` -- DROP TABLE IF EXISTS `xyzgroups`; /*!50001 DROP VIEW IF EXISTS `xyzgroups`*/; SET @saved_cs_client = @@character_set_client; SET character_set_client = utf8; /*!50001 CREATE TABLE `xyzgroups` ( `groupID` smallint(5) unsigned, `groupname` varchar(60), `GROUP_CONCAT(DISTINCT ``username`` ORDER BY ``username`` ASC SEPARAT` varchar(341) ) ENGINE=MyISAM */; SET character_set_client = @saved_cs_client; -- -- Dumping events for database 'zzz' -- -- -- Dumping routines for database 'zzz' -- -- -- Current Database: `zzz` -- USE `zzz`; -- -- Final view structure for view `xyzgroups` -- /*!50001 DROP TABLE IF EXISTS `xyzgroups`*/; /*!50001 DROP VIEW IF EXISTS `xyzgroups`*/; /*!50001 SET @saved_cs_client = @@character_set_client */; /*!50001 SET @saved_cs_results = @@character_set_results */; /*!50001 SET @saved_col_connection = @@collation_connection */; /*!50001 SET character_set_client = utf8 */; /*!50001 SET character_set_results = utf8 */; /*!50001 SET collation_connection = utf8_general_ci */; /*!50001 CREATE ALGORITHM=UNDEFINED */ /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ /*!50001 VIEW `xyzgroups` AS select `xyz_groups`.`groupID` AS `groupID`,`xyz_groups`.`groupname` AS `groupname`,group_concat(distinct `xyz_groups`.`username` order by `xyz_groups`.`username` ASC separator ',') AS `GROUP_CONCAT(DISTINCT ``username`` ORDER BY ``username`` ASC SEPARATOR ',')` from `xyz_groups` group by `xyz_groups`.`groupname` */; /*!50001 SET character_set_client = @saved_cs_client */; /*!50001 SET character_set_results = @saved_cs_results */; /*!50001 SET collation_connection = @saved_col_connection */; /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; /*!40101 SET SQL_MODE=@OLD_SQL_MODE */; /*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */; /*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */; /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; -- Dump completed on 2010-02-19 0:23:56 ------------------------------------------------------------ Suggested fix: - Don't create tables for views at all - Don't use aliases in the generated SQL as the alias for the group_concat is also group_concat