diff --git a/README.md b/README.md index 14c5ac06..eadfcd9a 100644 --- a/README.md +++ b/README.md @@ -19,6 +19,10 @@ This is a php version of linux's mysqldump in terminal "$ mysqldump -u username Out of the box, MySQLDump-PHP supports backing up table structures, the data itself, views and triggers. +MySQLDump-PHP is the only library that supports: +* output binary blobs as hex. +* resolves view dependencies (using Stand-In tables). + ## Important From version 2.0, connections to database are made using the standard DSN, documented in [PDO connection string](http://php.net/manual/en/ref.pdo-mysql.connection.php) diff --git a/src/Ifsnop/Mysqldump/Mysqldump.php b/src/Ifsnop/Mysqldump/Mysqldump.php index 65b13b40..ac6e0f86 100644 --- a/src/Ifsnop/Mysqldump/Mysqldump.php +++ b/src/Ifsnop/Mysqldump/Mysqldump.php @@ -480,7 +480,14 @@ private function exportViews() if (in_array($view, $this->dumpSettings['exclude-tables'], true)) { continue; } - $this->getViewStructure($view); + $this->tableColumnTypes[$view] = $this->getTableColumnTypes($view); + $this->getViewStructureTable($view); + } + foreach ($this->views as $view) { + if (in_array($view, $this->dumpSettings['exclude-tables'], true)) { + continue; + } + $this->getViewStructureView($view); } } } @@ -528,7 +535,18 @@ private function getTableStructure($tableName) break; } } + $this->tableColumnTypes[$tableName] = $this->getTableColumnTypes($tableName); + return; + } + /** + * Store column types to create data dumps and for Stand-In tables + * + * @param string $tableName Name of table to export + * @return array type column types detailed + */ + + function getTableColumnTypes($tableName) { $columnTypes = array(); $columns = $this->dbHandler->query( $this->typeAdapter->show_columns($tableName) @@ -540,36 +558,92 @@ private function getTableStructure($tableName) $columnTypes[$col['Field']] = array( 'is_numeric'=> $types['is_numeric'], 'is_blob' => $types['is_blob'], - 'type' => $types['type'] + 'type' => $types['type'], + 'type_sql' => $col['Type'] ); } - $this->tableColumnTypes[$tableName] = $columnTypes; - return; + + return $columnTypes; } /** - * View structure extractor + * View structure extractor, create table (avoids cyclic references) * * @todo move mysql specific code to typeAdapter * @param string $viewName Name of view to export * @return null */ - private function getViewStructure($viewName) + private function getViewStructureTable($viewName) { $ret = ''; if (!$this->dumpSettings['skip-comments']) { $ret = "--" . PHP_EOL . - "-- Table structure for view `${viewName}`" . PHP_EOL . + "-- Stand-In structure for view `${viewName}`" . PHP_EOL . "--" . PHP_EOL . PHP_EOL; } $this->compressManager->write($ret); $stmt = $this->typeAdapter->show_create_view($viewName); + + // create views as tables, to resolve dependencies foreach ($this->dbHandler->query($stmt) as $r) { if ($this->dumpSettings['add-drop-table']) { $this->compressManager->write( $this->typeAdapter->drop_view($viewName) ); } + + $this->compressManager->write( + $this->createStandInTable($viewName) + ); + break; + } + } + + /** + * Write a create table statement for the table Stand-In, show create + * table would return a create algorithm when used on a view + * + * @param string $viewName Name of view to export + * @return string create statement + */ + function createStandInTable($viewName) { + $ret = array(); + foreach($this->tableColumnTypes[$viewName] as $k => $v) { + $ret[] = "`${k}` ${v['type_sql']}"; + } + $ret = implode(PHP_EOL . ",", $ret); + + $ret = "CREATE TABLE IF NOT EXISTS `$viewName` (" . + PHP_EOL . $ret . PHP_EOL . ");" . PHP_EOL; + + return $ret; + } + + /** + * View structure extractor, create view + * + * @todo move mysql specific code to typeAdapter + * @param string $viewName Name of view to export + * @return null + */ + private function getViewStructureView($viewName) + { + $ret = ''; + if (!$this->dumpSettings['skip-comments']) { + $ret = "--" . PHP_EOL . + "-- View structure for view `${viewName}`" . PHP_EOL . + "--" . PHP_EOL . PHP_EOL; + } + $this->compressManager->write($ret); + $stmt = $this->typeAdapter->show_create_view($viewName); + + // create views, to resolve dependencies + // replacing tables with views + foreach ($this->dbHandler->query($stmt) as $r) { + // because we must replace table with view, we should delete it + $this->compressManager->write( + $this->typeAdapter->drop_view($viewName) + ); $this->compressManager->write( $this->typeAdapter->create_view($r) ); @@ -1277,6 +1351,7 @@ public function create_view($row) } $triggerStmt = $row['Create View']; + $triggerStmtReplaced1 = str_replace( "CREATE ALGORITHM", "/*!50001 CREATE ALGORITHM", diff --git a/tests/test.php b/tests/test.php index 74a31135..ea355ba9 100644 --- a/tests/test.php +++ b/tests/test.php @@ -55,4 +55,12 @@ $dump->start("mysqldump-php_test005.sql"); +$dump = new IMysqldump\Mysqldump( + "mysql:unix_socket=/var/run/mysqld/mysqld.sock;dbname=test006a", + "travis", + "", + array("no-data" => true, "add-drop-table" => true)); + +$dump->start("mysqldump-php_test006.sql"); + exit; diff --git a/tests/test.sh b/tests/test.sh index cd9427d2..479e4a6f 100755 --- a/tests/test.sh +++ b/tests/test.sh @@ -25,13 +25,22 @@ done index=0 mysql -e "CREATE USER 'travis'@'localhost' IDENTIFIED BY '';" 2> /dev/null +mysql -e "CREATE DATABASE test001;" 2> /dev/null +mysql -e "CREATE DATABASE test002;" 2> /dev/null +mysql -e "CREATE DATABASE test005;" 2> /dev/null +mysql -e "CREATE DATABASE test006a;" 2> /dev/null +mysql -e "CREATE DATABASE test006b;" 2> /dev/null mysql -e "GRANT ALL PRIVILEGES ON test001.* TO 'travis'@'localhost';" 2> /dev/null mysql -e "GRANT ALL PRIVILEGES ON test002.* TO 'travis'@'localhost';" 2> /dev/null mysql -e "GRANT ALL PRIVILEGES ON test005.* TO 'travis'@'localhost';" 2> /dev/null +mysql -e "GRANT ALL PRIVILEGES ON test006a.* TO 'travis'@'localhost';" 2> /dev/null +mysql -e "GRANT ALL PRIVILEGES ON test00ba.* TO 'travis'@'localhost';" 2> /dev/null +mysql -e "FLUSH PRIVILEGES;" 2> /dev/null mysql -uroot < test001.src.sql; ret[((index++))]=$? mysql -uroot --default-character-set=utf8mb4 < test002.src.sql; ret[((index++))]=$? mysql -uroot < test005.src.sql; ret[((index++))]=$? +mysql -uroot < test006.src.sql; ret[((index++))]=$? checksum_test001 > test001.src.checksum checksum_test002 > test002.src.checksum @@ -69,6 +78,9 @@ ret[((index++))]=$? mysql -uroot test005 < mysqldump-php_test005.sql ret[((index++))]=$? +mysql -uroot test006b < mysqldump-php_test006.sql +ret[((index++))]=$? + checksum_test001 > mysqldump-php_test001.checksum checksum_test002 > mysqldump-php_test002.checksum checksum_test005 > mysqldump-php_test005.checksum @@ -107,9 +119,13 @@ rm *.checksum 2> /dev/null rm *.filtered.sql 2> /dev/null rm mysqldump* 2> /dev/null +echo "Done $index tests" + total=0 for i in $(seq 0 20) ; do total=$((${ret[$i]} + $total)) done +echo "Exiting with code $total" + exit $total diff --git a/tests/test006.src.sql b/tests/test006.src.sql new file mode 100644 index 00000000..a14ec4d5 --- /dev/null +++ b/tests/test006.src.sql @@ -0,0 +1,107 @@ +-- phpMyAdmin SQL Dump +-- version 4.4.0 +-- http://www.phpmyadmin.net +-- +-- Servidor: localhost +-- Tiempo de generación: 31-08-2015 a las 19:26:58 +-- Versión del servidor: 5.5.42 +-- Versión de PHP: 5.6.7 + +DROP DATABASE IF EXISTS `test006a`; +CREATE DATABASE `test006a`; + +DROP DATABASE IF EXISTS `test006b`; +CREATE DATABASE `test006b`; + +USE `test006a`; + +SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; +SET time_zone = "+00:00"; + + +/*!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 */; + +-- +-- Base de datos: `my_test_db` +-- + +-- -------------------------------------------------------- + +-- +-- Estructura de tabla para la tabla `my_table` +-- + +CREATE TABLE IF NOT EXISTS `my_table` ( + `id` int(11) NOT NULL, + `name` varchar(300) DEFAULT NULL, + `lastname` varchar(300) DEFAULT NULL, + `username` varchar(300) DEFAULT NULL +) ENGINE=InnoDB DEFAULT CHARSET=latin1; + +-- -------------------------------------------------------- + +-- +-- Estructura Stand-in para la vista `my_view` +-- +CREATE TABLE IF NOT EXISTS `my_view` ( +`id` int(11) +,`name` varchar(300) +,`lastname` varchar(300) +,`username` varchar(300) +); + +-- -------------------------------------------------------- + +-- +-- Estructura Stand-in para la vista `view_of_my_table` +-- +CREATE TABLE IF NOT EXISTS `view_of_my_table` ( +`id` int(11) +,`name` varchar(300) +,`lastname` varchar(300) +,`username` varchar(300) +); + +-- -------------------------------------------------------- + +-- +-- Estructura para la vista `my_view` +-- +DROP TABLE IF EXISTS `my_view`; + +CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `my_view` AS select `view_of_my_table`.`id` AS `id`,`view_of_my_table`.`name` AS `name`,`view_of_my_table`.`lastname` AS `lastname`,`view_of_my_table`.`username` AS `username` from `view_of_my_table`; + +-- -------------------------------------------------------- + +-- +-- Estructura para la vista `view_of_my_table` +-- +DROP TABLE IF EXISTS `view_of_my_table`; + +CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `view_of_my_table` AS select `my_table`.`id` AS `id`,`my_table`.`name` AS `name`,`my_table`.`lastname` AS `lastname`,`my_table`.`username` AS `username` from `my_table`; + +-- +-- Índices para tablas volcadas +-- + +-- +-- Indices de la tabla `my_table` +-- +ALTER TABLE `my_table` + ADD PRIMARY KEY (`id`); + +-- +-- AUTO_INCREMENT de las tablas volcadas +-- + +-- +-- AUTO_INCREMENT de la tabla `my_table` +-- +ALTER TABLE `my_table` + MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; +/*!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 */;