├── .gitignore ├── tests ├── bootstrap.php ├── fixtures │ ├── jeff.sql │ ├── comment_change1.sql │ ├── comment_change2.sql │ ├── backslash.sql │ ├── fractional_seconds.sql │ ├── actor_definition.sql │ ├── jos_extwebdav_properties.sql │ ├── actor.sql │ ├── fk_deleted_column2.sql │ ├── fk_deleted_column_migration.sql │ ├── jos_ucm_history.sql │ ├── partition.sql │ ├── sakila_migration.sql │ ├── jos_finder_links.sql │ ├── fk_deleted_column1.sql │ ├── sakila.sql │ └── sakila_new.sql ├── AbstractTest.php ├── DifferTest.php └── ParserTest.php ├── .travis.yml ├── .php_cs ├── phpunit.xml.dist ├── php-mysql-diff ├── composer.json ├── src ├── Model │ ├── IndexColumn.php │ ├── Database.php │ ├── DatabaseDiff.php │ ├── ForeignKey.php │ ├── Index.php │ ├── Column.php │ ├── ChangedTable.php │ └── Table.php ├── Command │ ├── AbstractCommand.php │ ├── MigrateCommand.php │ └── DiffCommand.php ├── RegExpPattern.php ├── Differ.php └── Parser.php └── README.md /.gitignore: -------------------------------------------------------------------------------- 1 | /.idea 2 | /vendor 3 | -------------------------------------------------------------------------------- /tests/bootstrap.php: -------------------------------------------------------------------------------- 1 | in(__DIR__ . '/src'); 5 | 6 | return Symfony\CS\Config\Config::create() 7 | ->level(Symfony\CS\FixerInterface::SYMFONY_LEVEL) 8 | ->fixers(['concat_with_spaces', 'short_array_syntax', 'ordered_use', '-pre_increment', 'phpdoc_order', 'newline_after_open_tag', '-phpdoc_params']) 9 | ->finder($finder) 10 | ->setUsingCache(true); 11 | -------------------------------------------------------------------------------- /tests/AbstractTest.php: -------------------------------------------------------------------------------- 1 | 7 | 8 | 9 | ./tests 10 | 11 | 12 | 13 | 14 | 15 | src 16 | 17 | 18 | 19 | -------------------------------------------------------------------------------- /php-mysql-diff: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env php 2 | add(new MigrateCommand()); 19 | $application->add(new DiffCommand()); 20 | $application->run(); 21 | -------------------------------------------------------------------------------- /composer.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "camcima/php-mysql-diff", 3 | "type": "project", 4 | "homepage": "https://github.com/camcima/php-mysql-diff", 5 | "keywords": ["database","diff","mysql","migration","generator","script"], 6 | "license": "MIT", 7 | "authors": [ 8 | { 9 | "name": "Carlos Cima", 10 | "role": "Developer" 11 | } 12 | ], 13 | "require": { 14 | "php": ">5.6", 15 | "symfony/console": "^3.0" 16 | }, 17 | "require-dev": { 18 | "phpunit/phpunit": "^5.3", 19 | "fabpot/php-cs-fixer": "^1.11" 20 | }, 21 | "autoload": { 22 | "psr-4": { 23 | "Camcima\\MySqlDiff\\": "src/" 24 | } 25 | }, 26 | "bin": ["php-mysql-diff"] 27 | } 28 | -------------------------------------------------------------------------------- /tests/fixtures/fk_deleted_column2.sql: -------------------------------------------------------------------------------- 1 | -- Host: 127.0.0.1 Database: test_2 2 | 3 | DROP TABLE IF EXISTS `table_1`; 4 | CREATE TABLE `table_1` ( 5 | `id` int(11) NOT NULL AUTO_INCREMENT, 6 | `foreignId2` int(11) DEFAULT NULL, 7 | PRIMARY KEY (`id`), 8 | KEY `FK_table_1_table_2` (`foreignId2`), 9 | CONSTRAINT `FK_table_1_table_2` FOREIGN KEY (`foreignId2`) REFERENCES `table_2` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION 10 | ) ENGINE=InnoDB DEFAULT CHARSET=latin1 COMMENT='.'; 11 | 12 | 13 | DROP TABLE IF EXISTS `table_2`; 14 | CREATE TABLE `table_2` ( 15 | `id` int(11) NOT NULL AUTO_INCREMENT, 16 | PRIMARY KEY (`id`) 17 | ) ENGINE=InnoDB DEFAULT CHARSET=latin1 COMMENT='.'; 18 | -------------------------------------------------------------------------------- /tests/fixtures/fk_deleted_column_migration.sql: -------------------------------------------------------------------------------- 1 | # Disable Foreign Keys Check 2 | SET FOREIGN_KEY_CHECKS = 0; 3 | SET SQL_MODE = ''; 4 | 5 | # Deleted Tables 6 | 7 | # Changed Tables 8 | 9 | -- changed table `table_1` 10 | 11 | ALTER TABLE `table_1` 12 | DROP FOREIGN KEY `FK_table_1_table_2`, 13 | DROP INDEX `FK_table_1_table_2`, 14 | DROP COLUMN `foreignId`; 15 | ALTER TABLE `table_1` 16 | ADD COLUMN `foreignId2` int(11) DEFAULT NULL AFTER `id`, 17 | ADD KEY `FK_table_1_table_2` (`foreignId2`), 18 | ADD CONSTRAINT `FK_table_1_table_2` FOREIGN KEY (`foreignId2`) REFERENCES `table_2` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION; 19 | 20 | # New Tables 21 | 22 | # Disable Foreign Keys Check 23 | SET FOREIGN_KEY_CHECKS = 1; 24 | -------------------------------------------------------------------------------- /src/Model/IndexColumn.php: -------------------------------------------------------------------------------- 1 | column = $column; 27 | $this->indexFirstCharacters = $indexFirstCharacters; 28 | } 29 | 30 | /** 31 | * @return Column 32 | */ 33 | public function getColumn() 34 | { 35 | return $this->column; 36 | } 37 | 38 | /** 39 | * @return int 40 | */ 41 | public function getIndexFirstCharacters() 42 | { 43 | return $this->indexFirstCharacters; 44 | } 45 | } 46 | -------------------------------------------------------------------------------- /tests/fixtures/jos_ucm_history.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE IF NOT EXISTS `jos_ucm_history` ( 2 | `version_id` int(10) unsigned NOT NULL AUTO_INCREMENT, 3 | `ucm_item_id` int(10) unsigned NOT NULL, 4 | `ucm_type_id` int(10) unsigned NOT NULL, 5 | `version_note` varchar(255) NOT NULL DEFAULT '' COMMENT 'Optional version name', 6 | `save_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 7 | `editor_user_id` int(10) unsigned NOT NULL DEFAULT '0', 8 | `character_count` int(10) unsigned NOT NULL DEFAULT '0' COMMENT 'Number of characters in this version.', 9 | `sha1_hash` varchar(50) NOT NULL DEFAULT '' COMMENT 'SHA1 hash of the version''s data column.', 10 | `version_data` mediumtext NOT NULL COMMENT 'json-encoded string of version data', 11 | `keep_forever` tinyint(4) NOT NULL DEFAULT '0' COMMENT '0=auto delete; 1=keep', 12 | PRIMARY KEY (`version_id`), 13 | KEY `idx_ucm_item_id` (`ucm_type_id`,`ucm_item_id`), 14 | KEY `idx_save_date` (`save_date`) 15 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 AUTO_INCREMENT=1; -------------------------------------------------------------------------------- /src/Command/AbstractCommand.php: -------------------------------------------------------------------------------- 1 | verbose || $forceOutput) { 30 | $this->output->writeln($line); 31 | } 32 | } 33 | 34 | /** 35 | * @param string $string 36 | * @param bool $forceOutput 37 | */ 38 | protected function outputString($string = '', $forceOutput = false) 39 | { 40 | if ($this->verbose || $forceOutput) { 41 | $this->output->write($string); 42 | } 43 | } 44 | } 45 | -------------------------------------------------------------------------------- /tests/fixtures/partition.sql: -------------------------------------------------------------------------------- 1 | /*!40101 SET @saved_cs_client = @@character_set_client */; 2 | /*!40101 SET character_set_client = utf8 */; 3 | CREATE TABLE `export` ( 4 | `id_export` int(10) unsigned NOT NULL AUTO_INCREMENT, 5 | `export_type` varchar(50) NOT NULL, 6 | `filename` varchar(255) NOT NULL DEFAULT '', 7 | `file_content` longblob NOT NULL, 8 | `generated_at` datetime NOT NULL, 9 | `downloaded_at` datetime DEFAULT NULL, 10 | `generated_by` varchar(50) NOT NULL DEFAULT '', 11 | `created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP, 12 | `updated_at` timestamp NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, 13 | PRIMARY KEY (`id_export`) 14 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 15 | /*!50100 PARTITION BY RANGE (id_export) 16 | (PARTITION p0 VALUES LESS THAN (1000) ENGINE = InnoDB, 17 | PARTITION p1 VALUES LESS THAN (2000) ENGINE = InnoDB, 18 | PARTITION p2 VALUES LESS THAN (3000) ENGINE = InnoDB, 19 | PARTITION p3 VALUES LESS THAN (4000) ENGINE = InnoDB, 20 | PARTITION p4 VALUES LESS THAN MAXVALUE ENGINE = InnoDB) */; 21 | /*!40101 SET character_set_client = @saved_cs_client */; -------------------------------------------------------------------------------- /src/Model/Database.php: -------------------------------------------------------------------------------- 1 | tables; 21 | } 22 | 23 | /** 24 | * @param Table $table 25 | */ 26 | public function addTable(Table $table) 27 | { 28 | $this->tables[$table->getName()] = $table; 29 | } 30 | 31 | /** 32 | * @param string $tableName 33 | * 34 | * @throws \RuntimeException 35 | * 36 | * @return Table 37 | */ 38 | public function getTableByName($tableName) 39 | { 40 | if (!isset($this->tables[$tableName])) { 41 | throw new \RuntimeException(sprintf('Table "%s" not found in database!', $tableName)); 42 | } 43 | 44 | return $this->tables[$tableName]; 45 | } 46 | 47 | /** 48 | * @param string $tableName 49 | * 50 | * @return bool 51 | */ 52 | public function hasTable($tableName) 53 | { 54 | return isset($this->tables[$tableName]); 55 | } 56 | } 57 | -------------------------------------------------------------------------------- /tests/fixtures/sakila_migration.sql: -------------------------------------------------------------------------------- 1 | # Disable Foreign Keys Check 2 | SET FOREIGN_KEY_CHECKS = 0; 3 | SET SQL_MODE = ''; 4 | 5 | # Deleted Tables 6 | 7 | -- deleted table `test1` 8 | 9 | DROP TABLE `test1`; 10 | 11 | # Changed Tables 12 | 13 | -- changed table `test2` 14 | 15 | ALTER TABLE `test2` 16 | DROP PRIMARY KEY, 17 | DROP FOREIGN KEY `FK__test1`, 18 | DROP INDEX `FK__test1`; 19 | ALTER TABLE `test2` 20 | CHANGE COLUMN `id` `id` int(10) NOT NULL AUTO_INCREMENT FIRST, 21 | CHANGE COLUMN `fk` `fk` int(10) AFTER `id`, 22 | CHANGE COLUMN `val` `val` decimal(11,3) NOT NULL AFTER `fk`, 23 | CHANGE COLUMN `texto` `texto` char(60) NOT NULL DEFAULT 'default' AFTER `val`, 24 | ADD COLUMN `new_field` int(10) AFTER `datade`, 25 | ADD PRIMARY KEY (`id`,`new_field`), 26 | ADD UNIQUE KEY `FK__test1` (`datade`), 27 | ADD CONSTRAINT `FK__test3` FOREIGN KEY (`fk`) REFERENCES `test3` (`id`), 28 | ROW_FORMAT=COMPRESSED, 29 | KEY_BLOCK_SIZE=4, 30 | COMMENT='test1'; 31 | 32 | # New Tables 33 | 34 | -- new table `test3` 35 | 36 | CREATE TABLE `test3` ( 37 | `id` int(11) NOT NULL AUTO_INCREMENT, 38 | PRIMARY KEY (`id`) 39 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 40 | 41 | # Disable Foreign Keys Check 42 | SET FOREIGN_KEY_CHECKS = 1; 43 | -------------------------------------------------------------------------------- /tests/fixtures/jos_finder_links.sql: -------------------------------------------------------------------------------- 1 | CREATE TABLE `jos_finder_links` ( 2 | `link_id` int(10) unsigned NOT NULL AUTO_INCREMENT, 3 | `url` varchar(255) NOT NULL, 4 | `route` varchar(255) NOT NULL, 5 | `title` varchar(400) DEFAULT NULL, 6 | `description` varchar(255) DEFAULT NULL, 7 | `indexdate` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 8 | `md5sum` varchar(32) DEFAULT NULL, 9 | `published` tinyint(1) NOT NULL DEFAULT '1', 10 | `state` int(5) DEFAULT '1', 11 | `access` int(5) DEFAULT '0', 12 | `language` varchar(8) NOT NULL, 13 | `publish_start_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 14 | `publish_end_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 15 | `start_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 16 | `end_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 17 | `list_price` double unsigned NOT NULL DEFAULT '0', 18 | `sale_price` double unsigned NOT NULL DEFAULT '0', 19 | `type_id` int(11) NOT NULL, 20 | `object` mediumblob NOT NULL, 21 | PRIMARY KEY (`link_id`), 22 | KEY `idx_type` (`type_id`), 23 | KEY `idx_md5` (`md5sum`), 24 | KEY `idx_url` (`url`(75)), 25 | KEY `idx_published_list` (`published`,`state`,`access`,`publish_start_date`,`publish_end_date`,`list_price`), 26 | KEY `idx_published_sale` (`published`,`state`,`access`,`publish_start_date`,`publish_end_date`,`sale_price`), 27 | KEY `idx_title` (`title`(100)) 28 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; -------------------------------------------------------------------------------- /tests/fixtures/fk_deleted_column1.sql: -------------------------------------------------------------------------------- 1 | -- -------------------------------------------------------- 2 | -- Host: 127.0.0.1 3 | -- Server version: 5.7.10-log - MySQL Community Server (GPL) 4 | -- Server OS: Win64 5 | -- HeidiSQL Version: 9.4.0.5174 6 | -- -------------------------------------------------------- 7 | 8 | /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; 9 | /*!40101 SET NAMES utf8 */; 10 | /*!50503 SET NAMES utf8mb4 */; 11 | /*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */; 12 | /*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */; 13 | 14 | -- Dumping structure for table sakila.table_1 15 | CREATE TABLE IF NOT EXISTS `table_1` ( 16 | `id` int(11) NOT NULL AUTO_INCREMENT, 17 | `foreignId` int(11) DEFAULT NULL, 18 | PRIMARY KEY (`id`), 19 | KEY `FK_table_1_table_2` (`foreignId`), 20 | CONSTRAINT `FK_table_1_table_2` FOREIGN KEY (`foreignId`) REFERENCES `table_2` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION 21 | ) ENGINE=InnoDB DEFAULT CHARSET=latin1 COMMENT='.'; 22 | 23 | -- Data exporting was unselected. 24 | -- Dumping structure for table sakila.table_2 25 | CREATE TABLE IF NOT EXISTS `table_2` ( 26 | `id` int(11) NOT NULL AUTO_INCREMENT, 27 | PRIMARY KEY (`id`) 28 | ) ENGINE=InnoDB DEFAULT CHARSET=latin1 COMMENT='.'; 29 | 30 | -- Data exporting was unselected. 31 | /*!40101 SET SQL_MODE=IFNULL(@OLD_SQL_MODE, '') */; 32 | /*!40014 SET FOREIGN_KEY_CHECKS=IF(@OLD_FOREIGN_KEY_CHECKS IS NULL, 1, @OLD_FOREIGN_KEY_CHECKS) */; 33 | /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; 34 | -------------------------------------------------------------------------------- /src/Model/DatabaseDiff.php: -------------------------------------------------------------------------------- 1 | newTables; 31 | } 32 | 33 | /** 34 | * @param Table $table 35 | */ 36 | public function addNewTable(Table $table) 37 | { 38 | $this->newTables[] = $table; 39 | } 40 | 41 | /** 42 | * @return Table[] 43 | */ 44 | public function getDeletedTables() 45 | { 46 | return $this->deletedTables; 47 | } 48 | 49 | /** 50 | * @param Table $table 51 | */ 52 | public function addDeletedTable(Table $table) 53 | { 54 | $this->deletedTables[] = $table; 55 | } 56 | 57 | /** 58 | * @return ChangedTable[] 59 | */ 60 | public function getChangedTables() 61 | { 62 | return $this->changedTables; 63 | } 64 | 65 | /** 66 | * @param ChangedTable $changedTable 67 | */ 68 | public function addChangedTable(ChangedTable $changedTable) 69 | { 70 | $this->changedTables[] = $changedTable; 71 | } 72 | 73 | /** 74 | * @return bool 75 | */ 76 | public function isEmptyDifferences() 77 | { 78 | return empty($this->newTables) && empty($this->deletedTables) && empty($this->changedTables); 79 | } 80 | } 81 | -------------------------------------------------------------------------------- /src/Model/ForeignKey.php: -------------------------------------------------------------------------------- 1 | name = $name; 51 | } 52 | 53 | /** 54 | * @return string 55 | */ 56 | public function getName() 57 | { 58 | return $this->name; 59 | } 60 | 61 | /** 62 | * @return Table 63 | */ 64 | public function getParentTable() 65 | { 66 | return $this->parentTable; 67 | } 68 | 69 | /** 70 | * @param Table $parentTable 71 | */ 72 | public function setParentTable($parentTable) 73 | { 74 | $this->parentTable = $parentTable; 75 | } 76 | 77 | /** 78 | * @return string 79 | */ 80 | public function getColumnName() 81 | { 82 | return $this->columnName; 83 | } 84 | 85 | /** 86 | * @param string $columnName 87 | */ 88 | public function setColumnName($columnName) 89 | { 90 | $this->columnName = $columnName; 91 | } 92 | 93 | /** 94 | * @return string 95 | */ 96 | public function getReferenceTableName() 97 | { 98 | return $this->referenceTableName; 99 | } 100 | 101 | /** 102 | * @param string $referenceTableName 103 | */ 104 | public function setReferenceTableName($referenceTableName) 105 | { 106 | $this->referenceTableName = $referenceTableName; 107 | } 108 | 109 | /** 110 | * @return string 111 | */ 112 | public function getReferenceColumnName() 113 | { 114 | return $this->referenceColumnName; 115 | } 116 | 117 | /** 118 | * @param string $referenceColumnName 119 | */ 120 | public function setReferenceColumnName($referenceColumnName) 121 | { 122 | $this->referenceColumnName = $referenceColumnName; 123 | } 124 | 125 | /** 126 | * @return string 127 | */ 128 | public function getOnDeleteClause() 129 | { 130 | return $this->onDeleteClause; 131 | } 132 | 133 | /** 134 | * @param string $onDeleteClause 135 | */ 136 | public function setOnDeleteClause($onDeleteClause) 137 | { 138 | $this->onDeleteClause = $onDeleteClause; 139 | } 140 | 141 | /** 142 | * @return string 143 | */ 144 | public function getOnUpdateClause() 145 | { 146 | return $this->onUpdateClause; 147 | } 148 | 149 | /** 150 | * @param string $onUpdateClause 151 | */ 152 | public function setOnUpdateClause($onUpdateClause) 153 | { 154 | $this->onUpdateClause = $onUpdateClause; 155 | } 156 | 157 | /** 158 | * @return string 159 | */ 160 | public function generateCreationScript() 161 | { 162 | $foreignKeyOptions = []; 163 | 164 | if (!empty($this->onDeleteClause)) { 165 | $foreignKeyOptions[] = $this->onDeleteClause; 166 | } 167 | 168 | if (!empty($this->onUpdateClause)) { 169 | $foreignKeyOptions[] = $this->onUpdateClause; 170 | } 171 | 172 | return trim(sprintf('CONSTRAINT `%s` FOREIGN KEY (`%s`) REFERENCES `%s` (`%s`) %s', $this->name, $this->columnName, $this->referenceTableName, $this->referenceColumnName, implode(' ', $foreignKeyOptions))); 173 | } 174 | } 175 | -------------------------------------------------------------------------------- /src/Command/MigrateCommand.php: -------------------------------------------------------------------------------- 1 | setName('migrate') 21 | ->setDescription('Generate migration script') 22 | ->addArgument( 23 | 'from', 24 | InputArgument::REQUIRED, 25 | 'File path of the creation script of the initial database' 26 | ) 27 | ->addArgument( 28 | 'to', 29 | InputArgument::REQUIRED, 30 | 'File path of the creation script of the target database' 31 | ) 32 | ->addOption( 33 | 'output', 34 | 'o', 35 | InputOption::VALUE_REQUIRED, 36 | 'Output migration script to a file' 37 | ) 38 | ->addOption( 39 | 'ignore', 40 | 'i', 41 | InputOption::VALUE_REQUIRED, 42 | 'Table ignore list' 43 | ) 44 | ->addOption( 45 | 'progress', 46 | 'p', 47 | InputOption::VALUE_NONE, 48 | 'Display migration progress' 49 | ) 50 | ; 51 | } 52 | 53 | /** 54 | * @param InputInterface $input 55 | * @param OutputInterface $output 56 | * 57 | * @return int|null|void 58 | */ 59 | protected function execute(InputInterface $input, OutputInterface $output) 60 | { 61 | $this->output = $output; 62 | $this->verbose = !empty($input->getOption('output')); 63 | 64 | $this->outputLine('', true); 65 | $this->outputLine('PHP MySQL Diff 1.0.0'); 66 | $this->outputLine('----------------------------------------'); 67 | $this->outputLine(); 68 | 69 | $from = $input->getArgument('from'); 70 | $to = $input->getArgument('to'); 71 | 72 | if (!file_exists($from)) { 73 | $this->outputLine('' . sprintf('File not found: %s', $from) . ''); 74 | exit(1); 75 | } 76 | 77 | if (!file_exists($to)) { 78 | $this->outputLine('' . sprintf('File not found: %s', $to) . ''); 79 | exit(1); 80 | } 81 | 82 | $ignoreTables = []; 83 | if ($input->getOption('ignore')) { 84 | $ignoreListFile = $input->getOption('ignore'); 85 | if (!file_exists($ignoreListFile)) { 86 | $this->outputLine('' . sprintf('File not found: %s', $ignoreListFile) . ''); 87 | exit(1); 88 | } 89 | 90 | $ignoreTables = file($ignoreListFile); 91 | } 92 | 93 | $parser = new Parser(); 94 | 95 | $this->outputString('• Parsing initial database ......'); 96 | $fromDatabase = $parser->parseDatabase(file_get_contents($from)); 97 | $this->outputLine(' '); 98 | 99 | $this->outputString('• Parsing target database .......'); 100 | $toDatabase = $parser->parseDatabase(file_get_contents($to)); 101 | $this->outputLine(' '); 102 | 103 | $this->outputString('• Comparing databases ...........'); 104 | $differ = new Differ(); 105 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase, $ignoreTables); 106 | $this->outputLine(' '); 107 | 108 | if ($databaseDiff->isEmptyDifferences()) { 109 | $this->outputLine(); 110 | $this->outputLine('The databases have the same schema!'); 111 | exit; 112 | } 113 | 114 | $this->outputString('• Generating migration script ...'); 115 | $migrationScript = $differ->generateMigrationScript($databaseDiff, (bool) $input->getOption('progress')); 116 | $this->outputLine(' '); 117 | 118 | if ($this->verbose) { 119 | $this->outputString('• Writing output file ...........'); 120 | $outputFile = $input->getOption('output'); 121 | file_put_contents($outputFile, $migrationScript); 122 | $this->outputLine(' '); 123 | 124 | $this->outputLine(); 125 | $this->outputLine('Migration script generated!'); 126 | } else { 127 | $this->outputLine($migrationScript, true); 128 | } 129 | } 130 | } 131 | -------------------------------------------------------------------------------- /tests/DifferTest.php: -------------------------------------------------------------------------------- 1 | parseDatabase($this->getDatabaseFixture('sakila.sql')); 14 | $toDatabase = clone $fromDatabase; 15 | 16 | $differ = new Differ(); 17 | $result = $differ->diffDatabases($fromDatabase, $toDatabase); 18 | 19 | $this->assertInstanceOf(DatabaseDiff::class, $result); 20 | $this->assertEmpty($result->getNewTables()); 21 | $this->assertEmpty($result->getChangedTables()); 22 | $this->assertEmpty($result->getDeletedTables()); 23 | } 24 | 25 | public function testIsDiffingDifferentDatabases() 26 | { 27 | $parser = new Parser(); 28 | 29 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 30 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila_new.sql')); 31 | 32 | $differ = new Differ(); 33 | $result = $differ->diffDatabases($fromDatabase, $toDatabase); 34 | 35 | $this->assertInstanceOf(DatabaseDiff::class, $result); 36 | $this->assertCount(1, $result->getNewTables()); 37 | $this->assertEquals('test3', $result->getNewTables()[0]->getName()); 38 | $this->assertCount(1, $result->getChangedTables()); 39 | $this->assertEquals('test2', $result->getChangedTables()[0]->getFromTable()->getName()); 40 | $this->assertEquals('test2', $result->getChangedTables()[0]->getToTable()->getName()); 41 | $this->assertCount(1, $result->getDeletedTables()); 42 | $this->assertEquals('test1', $result->getDeletedTables()[0]->getName()); 43 | } 44 | 45 | public function testIsDiffingDifferentDatabasesWithIgnoredTables() 46 | { 47 | $parser = new Parser(); 48 | 49 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 50 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila_new.sql')); 51 | 52 | $differ = new Differ(); 53 | $result = $differ->diffDatabases($fromDatabase, $toDatabase, ['/^test[12]$/']); 54 | 55 | $this->assertInstanceOf(DatabaseDiff::class, $result); 56 | $this->assertCount(1, $result->getNewTables()); 57 | $this->assertEquals('test3', $result->getNewTables()[0]->getName()); 58 | $this->assertEmpty($result->getChangedTables()); 59 | $this->assertEmpty($result->getDeletedTables()); 60 | } 61 | 62 | public function testIsDiffingChangedTable() 63 | { 64 | $parser = new Parser(); 65 | 66 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 67 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila_new.sql')); 68 | 69 | $differ = new Differ(); 70 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase); 71 | 72 | $changedTable = $databaseDiff->getChangedTables()[0]; 73 | 74 | $differ->diffChangedTable($changedTable); 75 | } 76 | 77 | public function testIsDiffingChangedComment() 78 | { 79 | $parser = new Parser(); 80 | 81 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('comment_change1.sql')); 82 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('comment_change2.sql')); 83 | 84 | $differ = new Differ(); 85 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase); 86 | 87 | $this->assertContains('CHANGE COLUMN `field1` `field1` varchar(50) NOT NULL COMMENT \'New Comment\' FIRST;', $differ->generateMigrationScript($databaseDiff)); 88 | } 89 | 90 | public function testIsGeneratingMigrationScript() 91 | { 92 | $parser = new Parser(); 93 | 94 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 95 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('sakila_new.sql')); 96 | 97 | $differ = new Differ(); 98 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase); 99 | 100 | $result = $differ->generateMigrationScript($databaseDiff); 101 | 102 | $this->assertEquals($this->getDatabaseFixture('sakila_migration.sql'), $result); 103 | } 104 | 105 | public function testIsDiffingDeletedForeignKeyColumn() 106 | { 107 | $parser = new Parser(); 108 | 109 | $fromDatabase = $parser->parseDatabase($this->getDatabaseFixture('fk_deleted_column1.sql')); 110 | $toDatabase = $parser->parseDatabase($this->getDatabaseFixture('fk_deleted_column2.sql')); 111 | 112 | $differ = new Differ(); 113 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase); 114 | 115 | $this->assertEquals($this->getDatabaseFixture('fk_deleted_column_migration.sql'), $differ->generateMigrationScript($databaseDiff)); 116 | } 117 | } 118 | -------------------------------------------------------------------------------- /src/Model/Index.php: -------------------------------------------------------------------------------- 1 | name = $name; 51 | } 52 | 53 | /** 54 | * @return string 55 | */ 56 | public function getName() 57 | { 58 | return $this->name; 59 | } 60 | 61 | /** 62 | * @return Table 63 | */ 64 | public function getParentTable() 65 | { 66 | return $this->parentTable; 67 | } 68 | 69 | /** 70 | * @param Table $parentTable 71 | */ 72 | public function setParentTable($parentTable) 73 | { 74 | $this->parentTable = $parentTable; 75 | } 76 | 77 | /** 78 | * @return IndexColumn[] 79 | */ 80 | public function getIndexColumns() 81 | { 82 | return $this->indexColumns; 83 | } 84 | 85 | /** 86 | * @param Column[] $indexColumns 87 | */ 88 | public function setIndexColumns($indexColumns) 89 | { 90 | $this->indexColumns = $indexColumns; 91 | } 92 | 93 | /** 94 | * @param IndexColumn $indexColumn 95 | */ 96 | public function addIndexColumn(IndexColumn $indexColumn) 97 | { 98 | $this->indexColumns[] = $indexColumn; 99 | } 100 | 101 | /** 102 | * @param $columnName 103 | * 104 | * @throws \RuntimeException 105 | * 106 | * @return IndexColumn 107 | */ 108 | public function getIndexColumnByColumnName($columnName) 109 | { 110 | foreach ($this->indexColumns as $indexColumn) { 111 | if ($indexColumn->getColumn()->getName() === $columnName) { 112 | return $indexColumn; 113 | } 114 | } 115 | 116 | throw new \RuntimeException(sprintf('Index column "%s" not found!', $columnName)); 117 | } 118 | 119 | /** 120 | * @return bool 121 | */ 122 | public function isUnique() 123 | { 124 | return $this->unique; 125 | } 126 | 127 | /** 128 | * @param bool $unique 129 | */ 130 | public function setUnique($unique) 131 | { 132 | $this->unique = $unique; 133 | } 134 | 135 | /** 136 | * @return bool 137 | */ 138 | public function isSpatial() 139 | { 140 | return $this->spatial; 141 | } 142 | 143 | /** 144 | * @param bool $spatial 145 | */ 146 | public function setSpatial($spatial) 147 | { 148 | $this->spatial = $spatial; 149 | } 150 | 151 | /** 152 | * @return bool 153 | */ 154 | public function isFulltext() 155 | { 156 | return $this->fulltext; 157 | } 158 | 159 | /** 160 | * @param bool $fulltext 161 | */ 162 | public function setFulltext($fulltext) 163 | { 164 | $this->fulltext = $fulltext; 165 | } 166 | 167 | /** 168 | * @return string 169 | */ 170 | public function getOptions() 171 | { 172 | return $this->options; 173 | } 174 | 175 | /** 176 | * @param string $options 177 | */ 178 | public function setOptions($options) 179 | { 180 | $this->options = $options; 181 | } 182 | 183 | /** 184 | * @return string 185 | */ 186 | public function generateCreationScript() 187 | { 188 | $indexType = ''; 189 | if ($this->spatial) { 190 | $indexType = 'SPATIAL'; 191 | } elseif ($this->unique) { 192 | $indexType = 'UNIQUE'; 193 | } elseif ($this->fulltext) { 194 | $indexType = 'FULLTEXT'; 195 | } 196 | 197 | if (!empty($indexType)) { 198 | $indexType .= ' '; 199 | } 200 | 201 | $indexColumns = []; 202 | foreach ($this->indexColumns as $indexColumn) { 203 | $firstCharacters = ''; 204 | if ($indexColumn->getIndexFirstCharacters()) { 205 | $firstCharacters = sprintf('(%s)', $indexColumn->getIndexFirstCharacters()); 206 | } 207 | 208 | $indexColumns[] = sprintf('`%s`%s', $indexColumn->getColumn()->getName(), $firstCharacters); 209 | } 210 | 211 | $indexOptions = ''; 212 | if (!empty($this->options)) { 213 | $indexOptions = ' ' . $this->options; 214 | } 215 | 216 | return trim(sprintf('%sKEY `%s` (%s)%s', $indexType, $this->name, implode(',', $indexColumns), $indexOptions)); 217 | } 218 | } 219 | -------------------------------------------------------------------------------- /src/RegExpPattern.php: -------------------------------------------------------------------------------- 1 | \d+)\))?(?:\s+unsigned)?', 15 | 'float(?:\s+unsigned)?(?:\((?\d+),(?\d+)\))?', 16 | 'binary', 17 | 'real', 18 | 'decimal\((?\d+),(?\d+)\)(?:\s+unsigned)?', 19 | 'double(?:\((?\d+),(?\d+)\))?(?:\s+unsigned)?', 20 | '(?:datetime|time|timestamp)(?:\((?\d+)\))?', 21 | 'date', 22 | 'year\((?\d)\)', 23 | 'geometry', 24 | '(?:var|nvar)?char\((?\d+)\)', 25 | '(?:var)?binary\((?\d+)\)', 26 | '(?:tiny|medium|long)?text', 27 | '(?:tiny|medium|long)?blob', 28 | 'enum\(.+\)', 29 | 'set\(.+\)', 30 | ]; 31 | 32 | /** 33 | * @return string 34 | */ 35 | public static function tables() 36 | { 37 | $pattern = '/(?CREATE\s+TABLE\s+(?IF NOT EXISTS)?\s*`(?\S+)`\s+'; 38 | $pattern .= '\((?[^\/]+?)\)'; 39 | $pattern .= '('; 40 | $pattern .= '(?:\s+ENGINE\s*=\s*(?[^;\s]+))?\s*'; 41 | $pattern .= '|'; 42 | $pattern .= '(?:AUTO_INCREMENT\s*=\s*(?\d+))?\s*'; 43 | $pattern .= '|'; 44 | $pattern .= '(?:DEFAULT CHARSET\s*=\s*(?[^;\s]+))?\s*'; 45 | $pattern .= '|'; 46 | $pattern .= '(?:\s+ROW_FORMAT\s*=\s*(?[^;\s]+))?\s*'; 47 | $pattern .= '|'; 48 | $pattern .= '(?:\s+KEY_BLOCK_SIZE\s*=\s*(?[^;\s]+))?\s*'; 49 | $pattern .= '|'; 50 | $pattern .= '(?:COLLATE\s*=\s*.+?)?\s*'; 51 | $pattern .= '|'; 52 | $pattern .= '(?:COMMENT\s*=\s*\'(?([^\']|\'\')+)\')?\s*'; 53 | $pattern .= ')*'; 54 | $pattern .= ')(?:\/\*.+?\*\/)?\s*'; 55 | $pattern .= ';/'; 56 | $pattern .= 'si'; // modifier 57 | 58 | return $pattern; 59 | } 60 | 61 | /** 62 | * @return string 63 | */ 64 | public static function column() 65 | { 66 | $pattern = '/\s*'; 67 | $pattern .= '`(?\S+?)`\s+'; 68 | $pattern .= sprintf('(?%s)\s*', implode('|', self::$columnTypeRegExps)); 69 | $pattern .= '(?:CHARACTER SET\s+(?\S+))?\s*'; 70 | $pattern .= '(?:COLLATE\s+(?\S+))?\s*'; 71 | $pattern .= '(?NULL|NOT NULL)?\s*'; 72 | $pattern .= '(?AUTO_INCREMENT)?\s*'; 73 | $pattern .= '(?:DEFAULT (?\S+|\'[^\']+\'))?\s*'; 74 | $pattern .= '(?:ON UPDATE (?\S+))?\s*'; 75 | $pattern .= '(?:COMMENT \'(?([^\']|\'\')+)\')?\s*'; 76 | $pattern .= '(?:,|$)/'; 77 | $pattern .= 'i'; // modifier 78 | 79 | return $pattern; 80 | } 81 | 82 | /** 83 | * @return string 84 | */ 85 | public static function dataType() 86 | { 87 | return '/(?[^\(\s]+)\s*(?:\([^\)]+\))?\s*(?unsigned)?/i'; 88 | } 89 | 90 | /** 91 | * @return string 92 | */ 93 | public static function primaryKey() 94 | { 95 | return '/PRIMARY KEY \((?(?:`[^`]+`\s*(?:\(\d+\))?,?)+)\)/i'; 96 | } 97 | 98 | /** 99 | * @return string 100 | */ 101 | public static function foreignKey() 102 | { 103 | $pattern = '/CONSTRAINT `(?\S+?)`\s+FOREIGN KEY\s+'; 104 | $pattern .= '\(`(?\S+?)`\)\s+'; 105 | $pattern .= 'REFERENCES\s+`(?\S+?)`\s*'; 106 | $pattern .= '\(`(?\S+?)`\)\s*'; 107 | $pattern .= '(?ON DELETE .+?)?\s*'; 108 | $pattern .= '(?ON UPDATE .+?)?\s*'; 109 | $pattern .= '(?:,|$)/'; 110 | $pattern .= 'i'; // modifier 111 | 112 | return $pattern; 113 | } 114 | 115 | /** 116 | * @return string 117 | */ 118 | public static function index() 119 | { 120 | $pattern = '/\s*'; 121 | $pattern .= '(?SPATIAL)?\s*'; 122 | $pattern .= '(?UNIQUE)?\s*'; 123 | $pattern .= '(?FULLTEXT)?\s*'; 124 | $pattern .= 'KEY\s+`(?\S+?)`\s+'; 125 | $pattern .= '\((?(?:`[^`]+`(?:\(\d+\))?,?)+)\)\s*'; 126 | $pattern .= '(?[^,]+?)?\s*'; 127 | $pattern .= '(?:,|$)/'; 128 | $pattern .= 'i'; // modifier 129 | 130 | return $pattern; 131 | } 132 | 133 | /** 134 | * @return string 135 | */ 136 | public static function indexColumn() 137 | { 138 | $pattern = '/^(?[^\(]+)\s*'; 139 | $pattern .= '(?:\((?\d+)\))?$/'; 140 | $pattern .= 'i'; // modifier 141 | 142 | return $pattern; 143 | } 144 | } 145 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PHP MySQL Diff 2 | MySQL Schema Diff - Comparison / Migration Script Generation 3 | 4 | [![Travis-CI](https://img.shields.io/travis/camcima/php-mysql-diff/master.svg)](https://travis-ci.org/camcima/php-mysql-diff) 5 | 6 | ##### Why not `mysqldiff` from MySQL Utilities? 7 | MySQL Utilities includes a similar tool, `mysqldiff`, that is absolutely **horrible**! The purpose of this project is to provide a tool that is simple to use, reliable and fast. 8 | 9 | ## Installation 10 | 11 | To install PHP MySQL Diff, install Composer and issue the following command: 12 | 13 | ``` 14 | $ ./composer.phar global require camcima/php-mysql-diff 15 | ``` 16 | 17 | Then, make sure you have ~/.composer/vendor/bin in your PATH, and you're good to go: 18 | 19 | ``` 20 | export PATH="$PATH:$HOME/.composer/vendor/bin" 21 | ``` 22 | 23 | ## Update 24 | 25 | You can update PHP MySQL Diff through this command: 26 | 27 | ``` 28 | $ ./composer.phar global update camcima/php-mysql-diff 29 | ``` 30 | 31 | ## Usage 32 | 33 | ### Database Creation Scripts 34 | 35 | PHP MySQL Diff works with database creations scripts created by `mysqldump`, which is part of the MySQL distribution. In order to generate a database creation script, use the following command: 36 | 37 | ``` 38 | $ mysqldump -h hostname -u username -p -d dbname > outputfile.sql 39 | ``` 40 | 41 | This tool may not work with creation scripts generated by other means because it relies on finely tuned regular expressions that could not work if the file format is different. 42 | 43 | I chose to work with database creation scripts instead of working by connecting to the databases directly because it's more portable that way and you can work offline. In the future, I might develop the option to fetch the information directly from the database `INFORMATION_SCHEMA` table. 44 | 45 | ### Diff 46 | 47 | ``` 48 | $ php-mysql-diff diff [-i ] 49 | ``` 50 | 51 | where `from` is the path to the initial database creation script and `to` is the path to the target database creation script. 52 | 53 | **Ignore Tables** 54 | 55 | Use the `-i` option to ignore tables during comparison. The file format is a list of regular expressions to match the table names to be ignored, one per line. 56 | 57 | Example: 58 | ``` 59 | /^employee.+/ 60 | /^catalog$/ 61 | /^test[\d]$/ 62 | ``` 63 | 64 | **Output File** 65 | 66 | The output will be like this: 67 | 68 | ``` 69 | PHP MySQL Diff 1.0.0 70 | ---------------------------------------- 71 | 72 | • Parsing initial database ...... ✓ 73 | • Parsing target database ....... ✓ 74 | • Comparing databases ........... ✓ 75 | 76 | FROM tests\fixtures\sakila.sql 77 | TO tests\fixtures\sakila_new.sql 78 | 79 | ▲ table "test3" is in the TO database but not in the FROM database 80 | ▼ table "test1" is in the FROM database but not in the TO database 81 | ► table "test2" has a different schema 82 | ▲ column "new_field" is in the TO database but not in the FROM database 83 | ► column "id" has a different definition 84 | FROM `id` int(11) NOT NULL AUTO_INCREMENT 85 | TO `id` int(10) NOT NULL AUTO_INCREMENT 86 | ► column "fk" has a different definition 87 | FROM `fk` int(10) NOT NULL 88 | TO `fk` int(10) 89 | ► column "val" has a different definition 90 | FROM `val` decimal(10,2) NOT NULL 91 | TO `val` decimal(11,3) NOT NULL 92 | ► column "texto" has a different definition 93 | FROM `texto` varchar(60) DEFAULT NULL 94 | TO `texto` char(60) NOT NULL DEFAULT 'default' 95 | ► primary key has a different definition 96 | FROM PRIMARY KEY (`id`) 97 | TO PRIMARY KEY (`id`,`new_field`) 98 | ▲ foreign key "FK__test3" is in the TO database but not in the FROM database 99 | ▼ foreign key "FK__test1" is in the FROM database but not in the TO database 100 | ► index "FK__test1" has a different definition 101 | FROM KEY `FK__test1` (`fk`) 102 | TO UNIQUE KEY `FK__test1` (`datade`) 103 | 104 | Diff completed! 105 | ``` 106 | 107 | ▲ = only present in the TO database 108 | 109 | ► = different definitions between FROM and TO databases 110 | 111 | ▼ = only present in the FROM database 112 | 113 | ### Migration Script 114 | 115 | ``` 116 | $ php-mysql-diff migrate [-o ] [-i ] [-p] 117 | ``` 118 | 119 | where `from` is the path to the initial database creation script and `to` is the path to the target database creation script. 120 | 121 | **Ignore Tables** 122 | 123 | Use the `-i` option to ignore tables during comparison. The file format is a list of regular expressions to match the table names to be ignored, one per line. 124 | 125 | Example: 126 | ``` 127 | /^employee.+/ 128 | /^catalog$/ 129 | /^test[\d]$/ 130 | ``` 131 | 132 | **Output File** 133 | 134 | If the `-o` option is not used, the migration script will be output to the `stdout`. 135 | 136 | The output (with the `-o` option) will be like this: 137 | 138 | ``` 139 | PHP MySQL Diff 1.0.0 140 | ---------------------------------------- 141 | 142 | • Parsing initial database ...... ✓ 143 | • Parsing target database ....... ✓ 144 | • Comparing databases ........... ✓ 145 | • Generating migration script ... ✓ 146 | • Writing output file ........... ✓ 147 | 148 | Migration script generated! 149 | ``` 150 | 151 | and the migration script will look like this: 152 | 153 | ```sql 154 | # Disable Foreign Keys Check 155 | SET FOREIGN_KEY_CHECKS = 0; 156 | SET SQL_MODE = ''; 157 | 158 | # Deleted Tables 159 | 160 | -- deleted table `test1` 161 | 162 | DROP TABLE `test1`; 163 | 164 | # Changed Tables 165 | 166 | -- changed table `test2` 167 | 168 | ALTER TABLE `test2` 169 | DROP PRIMARY KEY, 170 | DROP FOREIGN KEY `FK__test1`, 171 | DROP INDEX `FK__test1`, 172 | CHANGE COLUMN `id` `id` int(10) NOT NULL AUTO_INCREMENT FIRST, 173 | CHANGE COLUMN `fk` `fk` int(10) AFTER `id`, 174 | CHANGE COLUMN `val` `val` decimal(11,3) NOT NULL AFTER `fk`, 175 | CHANGE COLUMN `texto` `texto` char(60) NOT NULL DEFAULT 'default' AFTER `val`, 176 | ADD COLUMN `new_field` int(10) AFTER `datade`, 177 | ADD PRIMARY KEY (`id`,`new_field`), 178 | ADD UNIQUE KEY `FK__test1` (`datade`), 179 | ADD CONSTRAINT `FK__test3` FOREIGN KEY (`fk`) REFERENCES `test3` (`id`); 180 | 181 | # New Tables 182 | 183 | -- new table `test3` 184 | 185 | CREATE TABLE `test3` ( 186 | `id` int(11) NOT NULL AUTO_INCREMENT, 187 | PRIMARY KEY (`id`) 188 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 189 | 190 | # Disable Foreign Keys Check 191 | SET FOREIGN_KEY_CHECKS = 1; 192 | ``` 193 | 194 | **Display Progress** 195 | 196 | For long running migrations, it is recommended to use the `-p` option to display the progress of the running migration. 197 | 198 | ## Contribute 199 | 200 | Feel free to send your contributions as PR. Make sure you update/write new tests to support your contribution. Please follow PSR-2. 201 | 202 | 203 | 204 | -------------------------------------------------------------------------------- /src/Command/DiffCommand.php: -------------------------------------------------------------------------------- 1 | setName('diff') 21 | ->setDescription('Show differences between initial and target database') 22 | ->addArgument( 23 | 'from', 24 | InputArgument::REQUIRED, 25 | 'File path of the creation script of the initial database' 26 | ) 27 | ->addArgument( 28 | 'to', 29 | InputArgument::REQUIRED, 30 | 'File path of the creation script of the target database' 31 | ) 32 | ->addOption( 33 | 'ignore', 34 | 'i', 35 | InputOption::VALUE_OPTIONAL, 36 | 'Table ignore list' 37 | ) 38 | ; 39 | } 40 | 41 | /** 42 | * @param InputInterface $input 43 | * @param OutputInterface $output 44 | * 45 | * @return int|null|void 46 | */ 47 | protected function execute(InputInterface $input, OutputInterface $output) 48 | { 49 | $this->output = $output; 50 | $this->verbose = true; 51 | 52 | $this->outputLine(); 53 | $this->outputLine('PHP MySQL Diff 1.0.0'); 54 | $this->outputLine('----------------------------------------'); 55 | $this->outputLine(); 56 | 57 | $from = $input->getArgument('from'); 58 | $to = $input->getArgument('to'); 59 | 60 | if (!file_exists($from)) { 61 | $this->outputLine('' . sprintf('File not found: %s', $from) . ''); 62 | exit(1); 63 | } 64 | 65 | if (!file_exists($to)) { 66 | $this->outputLine('' . sprintf('File not found: %s', $to) . ''); 67 | exit(1); 68 | } 69 | 70 | $ignoreTables = []; 71 | if ($input->getOption('ignore')) { 72 | $ignoreListFile = $input->getOption('ignore'); 73 | if (!file_exists($ignoreListFile)) { 74 | $this->outputLine('' . sprintf('File not found: %s', $ignoreListFile) . ''); 75 | exit(1); 76 | } 77 | 78 | $ignoreTables = file($ignoreListFile); 79 | } 80 | 81 | $parser = new Parser(); 82 | 83 | $this->outputString('• Parsing initial database ......'); 84 | $fromDatabase = $parser->parseDatabase(file_get_contents($from)); 85 | $this->outputLine(' '); 86 | 87 | $this->outputString('• Parsing target database .......'); 88 | $toDatabase = $parser->parseDatabase(file_get_contents($to)); 89 | $this->outputLine(' '); 90 | 91 | $this->outputString('• Comparing databases ...........'); 92 | $differ = new Differ(); 93 | $databaseDiff = $differ->diffDatabases($fromDatabase, $toDatabase, $ignoreTables); 94 | $this->outputLine(' '); 95 | $this->outputLine(); 96 | 97 | if ($databaseDiff->isEmptyDifferences()) { 98 | $this->outputLine('The databases have the same schema!'); 99 | exit; 100 | } 101 | 102 | $this->outputLine(sprintf('FROM %s', $from)); 103 | $this->outputLine(sprintf(' TO %s', $to)); 104 | $this->outputLine(); 105 | 106 | foreach ($databaseDiff->getNewTables() as $newTable) { 107 | $this->outputLine(sprintf(' table "%s" is in the TO database but not in the FROM database', $newTable->getName())); 108 | } 109 | 110 | foreach ($databaseDiff->getDeletedTables() as $deletedTable) { 111 | $this->outputLine(sprintf('▼ table "%s" is in the FROM database but not in the TO database', $deletedTable->getName())); 112 | } 113 | 114 | foreach ($databaseDiff->getChangedTables() as $changedTable) { 115 | $this->outputLine(sprintf(' table "%s" has a different schema', $changedTable->getName())); 116 | 117 | foreach ($changedTable->getNewColumns() as $newColumn) { 118 | $this->outputLine(sprintf(' column "%s" is in the TO database but not in the FROM database', $newColumn->getName())); 119 | } 120 | 121 | foreach ($changedTable->getDeletedColumns() as $deletedColumn) { 122 | $this->outputLine(sprintf(' ▼ column "%s" is in the FROM database but not in the TO database', $deletedColumn->getName())); 123 | } 124 | 125 | foreach ($changedTable->getChangedColumns() as $changedColumn) { 126 | $this->outputLine(sprintf(' column "%s" has a different definition', $changedColumn->getName())); 127 | $this->outputLine(sprintf(' FROM %s', $changedTable->getFromTable()->getColumnByName($changedColumn->getName())->generateCreationScript())); 128 | $this->outputLine(sprintf(' TO %s', $changedColumn->generateCreationScript())); 129 | } 130 | 131 | if ($changedTable->isDeletedPrimaryKey()) { 132 | $this->outputLine(sprintf(' ▼ primary key is in the FROM database but not in the TO database')); 133 | } elseif (!empty($changedTable->getChangedPrimaryKeys())) { 134 | if (empty($changedTable->getFromTable()->getPrimaryKeys())) { 135 | $this->outputLine(sprintf(' primary key is in the TO database but not in the FROM database')); 136 | } else { 137 | $this->outputLine(sprintf(' primary key has a different definition')); 138 | $this->outputLine(sprintf(' FROM %s', $changedTable->getFromTable()->generatePrimaryKeyCreationScript())); 139 | $this->outputLine(sprintf(' TO %s', $changedTable->getToTable()->generatePrimaryKeyCreationScript())); 140 | } 141 | } 142 | 143 | foreach ($changedTable->getNewForeignKeys() as $newForeignKey) { 144 | $this->outputLine(sprintf(' foreign key "%s" is in the TO database but not in the FROM database', $newForeignKey->getName())); 145 | } 146 | 147 | foreach ($changedTable->getDeletedForeignKeys() as $deletedForeignKey) { 148 | $this->outputLine(sprintf(' ▼ foreign key "%s" is in the FROM database but not in the TO database', $deletedForeignKey->getName())); 149 | } 150 | 151 | foreach ($changedTable->getChangedForeignKeys() as $changedForeignKey) { 152 | $this->outputLine(sprintf(' foreign key "%s" has a different definition', $changedForeignKey->getName())); 153 | $this->outputLine(sprintf(' FROM %s', $changedTable->getFromTable()->getForeignKeyByName($changedForeignKey->getName())->generateCreationScript())); 154 | $this->outputLine(sprintf(' TO %s', $changedForeignKey->generateCreationScript())); 155 | } 156 | 157 | foreach ($changedTable->getNewIndexes() as $newIndex) { 158 | $this->outputLine(sprintf(' index "%s" is in the TO database but not in the FROM database', $newIndex->getName())); 159 | } 160 | 161 | foreach ($changedTable->getDeletedIndexes() as $deletedIndex) { 162 | $this->outputLine(sprintf(' ▼ index "%s" is in the FROM database but not in the TO database', $deletedIndex->getName())); 163 | } 164 | 165 | foreach ($changedTable->getChangedIndexes() as $changedIndex) { 166 | $this->outputLine(sprintf(' index "%s" has a different definition', $changedIndex->getName())); 167 | $this->outputLine(sprintf(' FROM %s', $changedTable->getFromTable()->getIndexByName($changedIndex->getName())->generateCreationScript())); 168 | $this->outputLine(sprintf(' TO %s', $changedIndex->generateCreationScript())); 169 | } 170 | } 171 | 172 | $this->outputLine(); 173 | $this->outputLine('Diff completed!'); 174 | } 175 | } 176 | -------------------------------------------------------------------------------- /src/Model/Column.php: -------------------------------------------------------------------------------- 1 | name = $name; 111 | } 112 | 113 | /** 114 | * @return string 115 | */ 116 | public function getName() 117 | { 118 | return $this->name; 119 | } 120 | 121 | /** 122 | * @return Table 123 | */ 124 | public function getParentTable() 125 | { 126 | return $this->parentTable; 127 | } 128 | 129 | /** 130 | * @param Table $parentTable 131 | */ 132 | public function setParentTable($parentTable) 133 | { 134 | $this->parentTable = $parentTable; 135 | } 136 | 137 | /** 138 | * @return string 139 | */ 140 | public function getColumnType() 141 | { 142 | return $this->columnType; 143 | } 144 | 145 | /** 146 | * @param string $columnType 147 | */ 148 | public function setColumnType($columnType) 149 | { 150 | $this->columnType = $columnType; 151 | } 152 | 153 | /** 154 | * @return string 155 | */ 156 | public function getDataType() 157 | { 158 | return $this->dataType; 159 | } 160 | 161 | /** 162 | * @param string $dataType 163 | */ 164 | public function setDataType($dataType) 165 | { 166 | $this->dataType = $dataType; 167 | } 168 | 169 | /** 170 | * @return bool 171 | */ 172 | public function isUnsigned() 173 | { 174 | return $this->unsigned; 175 | } 176 | 177 | /** 178 | * @param bool $unsigned 179 | */ 180 | public function setUnsigned($unsigned) 181 | { 182 | $this->unsigned = $unsigned; 183 | } 184 | 185 | /** 186 | * @return string 187 | */ 188 | public function getCharacterSet() 189 | { 190 | return $this->characterSet; 191 | } 192 | 193 | /** 194 | * @param string $characterSet 195 | */ 196 | public function setCharacterSet($characterSet) 197 | { 198 | $this->characterSet = $characterSet; 199 | } 200 | 201 | /** 202 | * @return string 203 | */ 204 | public function getCollate() 205 | { 206 | return $this->collate; 207 | } 208 | 209 | /** 210 | * @param string $collate 211 | */ 212 | public function setCollate($collate) 213 | { 214 | $this->collate = $collate; 215 | } 216 | 217 | /** 218 | * @return int 219 | */ 220 | public function getLength() 221 | { 222 | return $this->length; 223 | } 224 | 225 | /** 226 | * @param int $length 227 | */ 228 | public function setLength($length) 229 | { 230 | $this->length = $length; 231 | } 232 | 233 | /** 234 | * @return int 235 | */ 236 | public function getPrecision() 237 | { 238 | return $this->precision; 239 | } 240 | 241 | /** 242 | * @param int $precision 243 | */ 244 | public function setPrecision($precision) 245 | { 246 | $this->precision = $precision; 247 | } 248 | 249 | /** 250 | * @return bool 251 | */ 252 | public function isNullable() 253 | { 254 | return $this->nullable; 255 | } 256 | 257 | /** 258 | * @param bool $nullable 259 | */ 260 | public function setNullable($nullable) 261 | { 262 | $this->nullable = $nullable; 263 | } 264 | 265 | /** 266 | * @return bool 267 | */ 268 | public function isAutoIncrement() 269 | { 270 | return $this->autoIncrement; 271 | } 272 | 273 | /** 274 | * @param bool $autoIncrement 275 | */ 276 | public function setAutoIncrement($autoIncrement) 277 | { 278 | $this->autoIncrement = $autoIncrement; 279 | } 280 | 281 | /** 282 | * @return bool 283 | */ 284 | public function isPrimaryKey() 285 | { 286 | return $this->primaryKey; 287 | } 288 | 289 | /** 290 | * @param bool $primaryKey 291 | */ 292 | public function setPrimaryKey($primaryKey) 293 | { 294 | $this->primaryKey = $primaryKey; 295 | } 296 | 297 | /** 298 | * @return int 299 | */ 300 | public function getPrimaryKeyLength() 301 | { 302 | return $this->primaryKeyLength; 303 | } 304 | 305 | /** 306 | * @param int $primaryKeyLength 307 | */ 308 | public function setPrimaryKeyLength($primaryKeyLength) 309 | { 310 | $this->primaryKeyLength = $primaryKeyLength; 311 | } 312 | 313 | /** 314 | * @return string 315 | */ 316 | public function getDefaultValue() 317 | { 318 | return $this->defaultValue; 319 | } 320 | 321 | /** 322 | * @param string $defaultValue 323 | */ 324 | public function setDefaultValue($defaultValue) 325 | { 326 | $this->defaultValue = $defaultValue; 327 | } 328 | 329 | /** 330 | * @return string 331 | */ 332 | public function getOnUpdateValue() 333 | { 334 | return $this->onUpdateValue; 335 | } 336 | 337 | /** 338 | * @param string $onUpdateValue 339 | */ 340 | public function setOnUpdateValue($onUpdateValue) 341 | { 342 | $this->onUpdateValue = $onUpdateValue; 343 | } 344 | 345 | /** 346 | * @return string 347 | */ 348 | public function getComment() 349 | { 350 | return $this->comment; 351 | } 352 | 353 | /** 354 | * @param string $comment 355 | */ 356 | public function setComment($comment) 357 | { 358 | $this->comment = $comment; 359 | } 360 | 361 | /** 362 | * @return Column 363 | */ 364 | public function getPreviousColumn() 365 | { 366 | return $this->previousColumn; 367 | } 368 | 369 | /** 370 | * @param Column $previousColumn 371 | */ 372 | public function setPreviousColumn(Column $previousColumn) 373 | { 374 | $this->previousColumn = $previousColumn; 375 | } 376 | 377 | /** 378 | * @return Column 379 | */ 380 | public function getNextColumn() 381 | { 382 | return $this->nextColumn; 383 | } 384 | 385 | /** 386 | * @param Column $nextColumn 387 | */ 388 | public function setNextColumn(Column $nextColumn) 389 | { 390 | $this->nextColumn = $nextColumn; 391 | } 392 | 393 | /** 394 | * @return int 395 | */ 396 | public function getOrder() 397 | { 398 | return $this->order; 399 | } 400 | 401 | /** 402 | * @param int $order 403 | */ 404 | public function setOrder($order) 405 | { 406 | $this->order = $order; 407 | } 408 | 409 | /** 410 | * @return string 411 | */ 412 | public function generateCreationScript() 413 | { 414 | $columnOptions = []; 415 | 416 | if ($this->characterSet) { 417 | $columnOptions[] = sprintf('CHARACTER SET %s', $this->characterSet); 418 | } 419 | 420 | if ($this->collate) { 421 | $columnOptions[] = sprintf('COLLATE %s', $this->collate); 422 | } 423 | 424 | if (!$this->nullable) { 425 | $columnOptions[] = 'NOT NULL'; 426 | } elseif ($this->columnType === 'timestamp') { 427 | $columnOptions[] = 'NULL'; 428 | } 429 | 430 | if ($this->autoIncrement) { 431 | $columnOptions[] = 'AUTO_INCREMENT'; 432 | } 433 | 434 | if (!empty($this->defaultValue)) { 435 | $columnOptions[] = sprintf('DEFAULT %s', $this->defaultValue); 436 | } 437 | 438 | if (!empty($this->onUpdateValue)) { 439 | $columnOptions[] = sprintf('ON UPDATE %s', $this->onUpdateValue); 440 | } 441 | 442 | if (!empty($this->comment)) { 443 | $columnOptions[] = sprintf('COMMENT \'%s\'', str_replace('\'', '\'\'', $this->comment)); 444 | } 445 | 446 | return trim(sprintf('`%s` %s %s', $this->name, $this->columnType, implode(' ', $columnOptions))); 447 | } 448 | } 449 | -------------------------------------------------------------------------------- /src/Differ.php: -------------------------------------------------------------------------------- 1 | getTables() as $fromTable) { 27 | if ($this->isTableIgnored($fromTable->getName(), $ignoreList)) { 28 | continue; 29 | } 30 | 31 | if (!$toDatabase->hasTable($fromTable->getName())) { 32 | $databaseDiff->addDeletedTable($fromTable); 33 | continue; 34 | } 35 | 36 | $toTable = $toDatabase->getTableByName($fromTable->getName()); 37 | 38 | if ($fromTable->generateCreationScript(true) !== $toTable->generateCreationScript(true)) { 39 | $changedTable = new ChangedTable($fromTable, $toTable); 40 | $this->diffChangedTable($changedTable); 41 | 42 | if (!empty($changedTable->generateAlterScript())) { 43 | $databaseDiff->addChangedTable($changedTable); 44 | } 45 | } 46 | } 47 | 48 | foreach ($toDatabase->getTables() as $toTable) { 49 | if ($this->isTableIgnored($toTable->getName(), $ignoreList)) { 50 | continue; 51 | } 52 | 53 | if (!$fromDatabase->hasTable($toTable->getName())) { 54 | $databaseDiff->addNewTable($toTable); 55 | } 56 | } 57 | 58 | return $databaseDiff; 59 | } 60 | 61 | /** 62 | * @param ChangedTable $changedTable 63 | */ 64 | public function diffChangedTable(ChangedTable $changedTable) 65 | { 66 | $this->diffColumns($changedTable); 67 | $this->diffPrimaryKey($changedTable); 68 | $this->diffIndexes($changedTable); 69 | $this->diffForeignKeys($changedTable); 70 | } 71 | 72 | /** 73 | * @param ChangedTable $changedTable 74 | */ 75 | private function diffColumns(ChangedTable $changedTable) 76 | { 77 | $fromTable = $changedTable->getFromTable(); 78 | $toTable = $changedTable->getToTable(); 79 | 80 | // Determine deleted columns 81 | foreach ($fromTable->getColumns() as $fromColumn) { 82 | if (!$toTable->hasColumn($fromColumn->getName())) { 83 | $changedTable->addDeletedColumn($fromColumn); 84 | } 85 | } 86 | 87 | foreach ($toTable->getColumns() as $toColumn) { 88 | 89 | // Determine new columns 90 | if (!$fromTable->hasColumn($toColumn->getName())) { 91 | $changedTable->addNewColumn($toColumn); 92 | continue; 93 | } 94 | 95 | // Determine changed columns 96 | $fromColumn = $fromTable->getColumnByName($toColumn->getName()); 97 | if ($toColumn->generateCreationScript() !== $fromColumn->generateCreationScript()) { 98 | $changedTable->addChangedColumn($toColumn); 99 | continue; 100 | } 101 | 102 | if (!$fromColumn->getPreviousColumn() && !$toColumn->getPreviousColumn()) { 103 | continue; 104 | } 105 | if (!$fromColumn->getPreviousColumn() && $toColumn->getPreviousColumn() instanceof Column) { 106 | $this->addChangedColumn($changedTable, $toColumn); 107 | } elseif ($fromColumn->getPreviousColumn() instanceof Column && !$toColumn->getPreviousColumn()) { 108 | $this->addChangedColumn($changedTable, $toColumn); 109 | } elseif ($fromColumn->getPreviousColumn()->getName() !== $toColumn->getPreviousColumn()->getName()) { 110 | $this->addChangedColumn($changedTable, $toColumn); 111 | } 112 | } 113 | } 114 | 115 | /** 116 | * @param ChangedTable $changedTable 117 | * @param Column $column 118 | */ 119 | private function addChangedColumn(ChangedTable $changedTable, Column $column) 120 | { 121 | if (!$changedTable->hasNewColumn($column->getName())) { 122 | $changedTable->addChangedColumn($column); 123 | } 124 | 125 | if (!$column->getNextColumn()) { 126 | return; 127 | } 128 | 129 | $this->addChangedColumn($changedTable, $column->getNextColumn()); 130 | } 131 | 132 | /** 133 | * @param ChangedTable $changedTable 134 | */ 135 | private function diffPrimaryKey(ChangedTable $changedTable) 136 | { 137 | $fromTable = $changedTable->getFromTable(); 138 | $toTable = $changedTable->getToTable(); 139 | 140 | if (empty($toTable->getPrimaryKeys()) && !empty($fromTable->getPrimaryKeys())) { 141 | $changedTable->setDeletedPrimaryKey(true); 142 | 143 | return; 144 | } 145 | 146 | if ($fromTable->generatePrimaryKeyCreationScript() !== $toTable->generatePrimaryKeyCreationScript()) { 147 | $changedTable->setChangedPrimaryKeys($toTable->getPrimaryKeys()); 148 | } 149 | } 150 | 151 | /** 152 | * @param ChangedTable $changedTable 153 | */ 154 | private function diffIndexes(ChangedTable $changedTable) 155 | { 156 | $fromTable = $changedTable->getFromTable(); 157 | $toTable = $changedTable->getToTable(); 158 | 159 | // Determine deleted indexes 160 | foreach ($fromTable->getIndexes() as $fromIndex) { 161 | if (!$toTable->hasIndex($fromIndex->getName())) { 162 | $changedTable->addDeletedIndex($fromIndex); 163 | } 164 | } 165 | 166 | foreach ($toTable->getIndexes() as $toIndex) { 167 | 168 | // Determine new indexes 169 | if (!$fromTable->hasIndex($toIndex->getName())) { 170 | $changedTable->addNewIndex($toIndex); 171 | continue; 172 | } 173 | 174 | // Determine changed indexes 175 | $fromIndex = $fromTable->getIndexByName($toIndex->getName()); 176 | if ($toIndex->generateCreationScript() !== $fromIndex->generateCreationScript()) { 177 | $changedTable->addChangedIndex($toIndex); 178 | } 179 | } 180 | } 181 | 182 | /** 183 | * @param ChangedTable $changedTable 184 | */ 185 | private function diffForeignKeys(ChangedTable $changedTable) 186 | { 187 | $fromTable = $changedTable->getFromTable(); 188 | $toTable = $changedTable->getToTable(); 189 | 190 | // Determine deleted foreign keys 191 | foreach ($fromTable->getForeignKeys() as $fromForeignKey) { 192 | if (!$toTable->hasForeignKey($fromForeignKey->getName())) { 193 | $changedTable->addDeletedForeignKey($fromForeignKey); 194 | } 195 | } 196 | 197 | foreach ($toTable->getForeignKeys() as $toForeignKey) { 198 | 199 | // Determine new foreign keys 200 | if (!$fromTable->hasForeignKey($toForeignKey->getName())) { 201 | $changedTable->addNewForeignKey($toForeignKey); 202 | continue; 203 | } 204 | 205 | // Determine changed foreign keys 206 | $fromForeignKey = $fromTable->getForeignKeyByName($toForeignKey->getName()); 207 | if ($toForeignKey->generateCreationScript() !== $fromForeignKey->generateCreationScript()) { 208 | $changedTable->addChangedForeignKey($toForeignKey); 209 | } 210 | } 211 | } 212 | 213 | /** 214 | * @param DatabaseDiff $databaseDiff 215 | * @param bool $displayProgress 216 | * 217 | * @return string 218 | */ 219 | public function generateMigrationScript(DatabaseDiff $databaseDiff, $displayProgress = false) 220 | { 221 | return implode(PHP_EOL, $this->generateMigrationScriptArray($databaseDiff, $displayProgress)); 222 | } 223 | 224 | /** 225 | * @param DatabaseDiff $databaseDiff 226 | * @param bool $displayProgress 227 | * 228 | * @return array 229 | */ 230 | public function generateMigrationScriptArray(DatabaseDiff $databaseDiff, $displayProgress = false) 231 | { 232 | $migrationScript = []; 233 | $migrationScript[] = '# Disable Foreign Keys Check'; 234 | $migrationScript[] = 'SET FOREIGN_KEY_CHECKS = 0;'; 235 | $migrationScript[] = 'SET SQL_MODE = \'\';'; 236 | 237 | $migrationScript[] = ''; 238 | $migrationScript[] = '# Deleted Tables'; 239 | foreach ($databaseDiff->getDeletedTables() as $deletedTable) { 240 | $migrationScript[] = ''; 241 | $migrationScript[] = sprintf('-- deleted table `%s`', $deletedTable->getName()); 242 | $migrationScript[] = ''; 243 | 244 | if ($displayProgress) { 245 | $migrationScript[] = sprintf("SELECT 'Dropping table %s';", $deletedTable->getName()); 246 | } 247 | 248 | $migrationScript[] = sprintf('DROP TABLE `%s`;', $deletedTable->getName()); 249 | } 250 | 251 | $migrationScript[] = ''; 252 | $migrationScript[] = '# Changed Tables'; 253 | foreach ($databaseDiff->getChangedTables() as $changedTable) { 254 | $migrationScript[] = ''; 255 | $migrationScript[] = sprintf('-- changed table `%s`', $changedTable->getName()); 256 | $migrationScript[] = ''; 257 | 258 | if ($displayProgress) { 259 | $migrationScript[] = sprintf("SELECT 'Altering table %s';", $changedTable->getName()); 260 | } 261 | 262 | $migrationScript[] = $changedTable->generateAlterScript(); 263 | } 264 | $migrationScript[] = ''; 265 | $migrationScript[] = '# New Tables'; 266 | 267 | foreach ($databaseDiff->getNewTables() as $newTable) { 268 | $migrationScript[] = ''; 269 | $migrationScript[] = sprintf('-- new table `%s`', $newTable->getName()); 270 | $migrationScript[] = ''; 271 | 272 | if ($displayProgress) { 273 | $migrationScript[] = sprintf("SELECT 'Creating table %s';", $newTable->getName()); 274 | } 275 | 276 | $migrationScript[] = $newTable->generateCreationScript(true); 277 | } 278 | 279 | $migrationScript[] = ''; 280 | $migrationScript[] = '# Disable Foreign Keys Check'; 281 | $migrationScript[] = 'SET FOREIGN_KEY_CHECKS = 1;'; 282 | $migrationScript[] = ''; 283 | 284 | return $migrationScript; 285 | } 286 | 287 | /** 288 | * @param string $tableName 289 | * @param array $ignoreList 290 | * 291 | * @return bool 292 | */ 293 | private function isTableIgnored($tableName, array $ignoreList) 294 | { 295 | foreach ($ignoreList as $ignoreRegExp) { 296 | if (preg_match($ignoreRegExp, $tableName) === 1) { 297 | return true; 298 | } 299 | } 300 | 301 | return false; 302 | } 303 | } 304 | -------------------------------------------------------------------------------- /src/Model/ChangedTable.php: -------------------------------------------------------------------------------- 1 | fromTable = $fromTable; 82 | $this->toTable = $toTable; 83 | } 84 | 85 | /** 86 | * @return string 87 | */ 88 | public function getName() 89 | { 90 | return $this->toTable->getName(); 91 | } 92 | 93 | /** 94 | * @return Table 95 | */ 96 | public function getFromTable() 97 | { 98 | return $this->fromTable; 99 | } 100 | 101 | /** 102 | * @return Table 103 | */ 104 | public function getToTable() 105 | { 106 | return $this->toTable; 107 | } 108 | 109 | /** 110 | * @return Column[] 111 | */ 112 | public function getNewColumns() 113 | { 114 | return $this->newColumns; 115 | } 116 | 117 | /** 118 | * @param Column $newColumn 119 | */ 120 | public function addNewColumn(Column $newColumn) 121 | { 122 | $this->newColumns[$newColumn->getName()] = $newColumn; 123 | 124 | if (isset($this->changedColumns[$newColumn->getName()])) { 125 | unset($this->changedColumns[$newColumn->getName()]); 126 | } 127 | } 128 | 129 | /** 130 | * @param $columnName 131 | * 132 | * @return bool 133 | */ 134 | public function hasNewColumn($columnName) 135 | { 136 | return isset($this->newColumns[$columnName]); 137 | } 138 | 139 | /** 140 | * @return Column[] 141 | */ 142 | public function getDeletedColumns() 143 | { 144 | return $this->deletedColumns; 145 | } 146 | 147 | /** 148 | * @param Column $deletedColumn 149 | */ 150 | public function addDeletedColumn(Column $deletedColumn) 151 | { 152 | $this->deletedColumns[$deletedColumn->getName()] = $deletedColumn; 153 | } 154 | 155 | /** 156 | * @return Column[] 157 | */ 158 | public function getChangedColumns() 159 | { 160 | return $this->changedColumns; 161 | } 162 | 163 | /** 164 | * @param Column $changedColumn 165 | */ 166 | public function addChangedColumn(Column $changedColumn) 167 | { 168 | if (!isset($this->changedColumns[$changedColumn->getName()])) { 169 | $this->changedColumns[$changedColumn->getName()] = $changedColumn; 170 | } 171 | } 172 | 173 | /** 174 | * @return Column[] 175 | */ 176 | public function getChangedPrimaryKeys() 177 | { 178 | return $this->changedPrimaryKeys; 179 | } 180 | 181 | /** 182 | * @param Column[] $changedPrimaryKeys 183 | */ 184 | public function setChangedPrimaryKeys($changedPrimaryKeys) 185 | { 186 | $this->changedPrimaryKeys = $changedPrimaryKeys; 187 | } 188 | 189 | /** 190 | * @return bool 191 | */ 192 | public function isDeletedPrimaryKey() 193 | { 194 | return $this->deletedPrimaryKey; 195 | } 196 | 197 | /** 198 | * @param bool $deletedPrimaryKey 199 | */ 200 | public function setDeletedPrimaryKey($deletedPrimaryKey) 201 | { 202 | $this->deletedPrimaryKey = $deletedPrimaryKey; 203 | } 204 | 205 | /** 206 | * @return Index[] 207 | */ 208 | public function getNewIndexes() 209 | { 210 | return $this->newIndexes; 211 | } 212 | 213 | /** 214 | * @param Index $newIndex 215 | */ 216 | public function addNewIndex(Index $newIndex) 217 | { 218 | $this->newIndexes[$newIndex->getName()] = $newIndex; 219 | } 220 | 221 | /** 222 | * @return Index[] 223 | */ 224 | public function getDeletedIndexes() 225 | { 226 | return $this->deletedIndexes; 227 | } 228 | 229 | /** 230 | * @param Index $deletedIndex 231 | */ 232 | public function addDeletedIndex(Index $deletedIndex) 233 | { 234 | $this->deletedIndexes[$deletedIndex->getName()] = $deletedIndex; 235 | } 236 | 237 | /** 238 | * @return Index[] 239 | */ 240 | public function getChangedIndexes() 241 | { 242 | return $this->changedIndexes; 243 | } 244 | 245 | /** 246 | * @param Index $changedIndex 247 | */ 248 | public function addChangedIndex(Index $changedIndex) 249 | { 250 | $this->changedIndexes[$changedIndex->getName()] = $changedIndex; 251 | } 252 | 253 | /** 254 | * @return ForeignKey[] 255 | */ 256 | public function getNewForeignKeys() 257 | { 258 | return $this->newForeignKeys; 259 | } 260 | 261 | /** 262 | * @param ForeignKey $newForeignKey 263 | */ 264 | public function addNewForeignKey(ForeignKey $newForeignKey) 265 | { 266 | $this->newForeignKeys[$newForeignKey->getName()] = $newForeignKey; 267 | } 268 | 269 | /** 270 | * @return ForeignKey[] 271 | */ 272 | public function getDeletedForeignKeys() 273 | { 274 | return $this->deletedForeignKeys; 275 | } 276 | 277 | /** 278 | * @param ForeignKey $deletedForeignKey 279 | */ 280 | public function addDeletedForeignKey(ForeignKey $deletedForeignKey) 281 | { 282 | $this->deletedForeignKeys[$deletedForeignKey->getName()] = $deletedForeignKey; 283 | } 284 | 285 | /** 286 | * @return ForeignKey[] 287 | */ 288 | public function getChangedForeignKeys() 289 | { 290 | return $this->changedForeignKeys; 291 | } 292 | 293 | /** 294 | * @param ForeignKey $changedForeignKey 295 | */ 296 | public function addChangedForeignKey(ForeignKey $changedForeignKey) 297 | { 298 | $this->changedForeignKeys[$changedForeignKey->getName()] = $changedForeignKey; 299 | } 300 | 301 | /** 302 | * @return string 303 | */ 304 | public function generateAlterScript() 305 | { 306 | $tableDrops = []; 307 | $tableChanges = []; 308 | 309 | if ($this->deletedPrimaryKey || (!empty($this->fromTable->getPrimaryKeys()) && !empty($this->changedPrimaryKeys))) { 310 | $tableDrops[] = 'DROP PRIMARY KEY'; 311 | } 312 | 313 | foreach ($this->deletedForeignKeys as $deletedForeignKey) { 314 | $tableDrops[] = sprintf('DROP FOREIGN KEY `%s`', $deletedForeignKey->getName()); 315 | } 316 | 317 | foreach ($this->changedForeignKeys as $changedForeignKey) { 318 | $tableDrops[] = sprintf('DROP FOREIGN KEY `%s`', $changedForeignKey->getName()); 319 | } 320 | 321 | foreach ($this->deletedIndexes as $deletedIndex) { 322 | $tableDrops[] = sprintf('DROP INDEX `%s`', $deletedIndex->getName()); 323 | } 324 | 325 | foreach ($this->changedIndexes as $changedIndex) { 326 | $tableDrops[] = sprintf('DROP INDEX `%s`', $changedIndex->getName()); 327 | } 328 | 329 | foreach ($this->deletedColumns as $deletedColumn) { 330 | $tableDrops[] = sprintf('DROP COLUMN `%s`', $deletedColumn->getName()); 331 | } 332 | 333 | $columnStatements = []; 334 | 335 | foreach ($this->changedColumns as $changedColumn) { 336 | $columnStatements[$changedColumn->getOrder()] = sprintf('CHANGE COLUMN `%s` %s %s', $changedColumn->getName(), $changedColumn->generateCreationScript(), $this->getAfterClause($changedColumn)); 337 | } 338 | 339 | foreach ($this->newColumns as $newColumn) { 340 | $columnStatements[$newColumn->getOrder()] = sprintf('ADD COLUMN %s %s', $newColumn->generateCreationScript(), $this->getAfterClause($newColumn)); 341 | } 342 | 343 | ksort($columnStatements); 344 | 345 | foreach ($columnStatements as $columnStatement) { 346 | $tableChanges[] = $columnStatement; 347 | } 348 | 349 | if (!empty($this->changedPrimaryKeys)) { 350 | $primaryKeyColumnNames = []; 351 | foreach ($this->changedPrimaryKeys as $primaryKeyColumn) { 352 | $primaryKeyColumnNames[] = sprintf('`%s`', $primaryKeyColumn->getName()); 353 | } 354 | 355 | $tableChanges[] = sprintf('ADD PRIMARY KEY (%s)', implode(',', $primaryKeyColumnNames)); 356 | } 357 | 358 | foreach ($this->changedIndexes as $changedIndex) { 359 | $tableChanges[] = sprintf('ADD %s', $changedIndex->generateCreationScript()); 360 | } 361 | 362 | foreach ($this->newIndexes as $newIndex) { 363 | $tableChanges[] = sprintf('ADD %s', $newIndex->generateCreationScript()); 364 | } 365 | 366 | foreach ($this->changedForeignKeys as $changedForeignKey) { 367 | $tableChanges[] = sprintf('ADD %s', $changedForeignKey->generateCreationScript()); 368 | } 369 | 370 | foreach ($this->newForeignKeys as $newForeignKey) { 371 | $tableChanges[] = sprintf('ADD %s', $newForeignKey->generateCreationScript()); 372 | } 373 | 374 | if ($this->fromTable->getEngine() !== $this->toTable->getEngine()) { 375 | $tableChanges[] = sprintf('ENGINE=%s', $this->toTable->getEngine()); 376 | } 377 | 378 | if ($this->fromTable->getDefaultCharset() !== $this->toTable->getDefaultCharset()) { 379 | $tableChanges[] = sprintf('DEFAULT CHARSET=%s', $this->toTable->getDefaultCharset()); 380 | } 381 | 382 | if ($this->fromTable->getRowFormat() !== $this->toTable->getRowFormat()) { 383 | $tableChanges[] = sprintf('ROW_FORMAT=%s', $this->toTable->getRowFormat()); 384 | } 385 | 386 | if ($this->fromTable->getKeyBlockSize() !== $this->toTable->getKeyBlockSize()) { 387 | $tableChanges[] = sprintf('KEY_BLOCK_SIZE=%s', $this->toTable->getKeyBlockSize()); 388 | } 389 | 390 | if ($this->fromTable->getComment() !== $this->toTable->getComment()) { 391 | $tableChanges[] = sprintf('COMMENT=\'%s\'', str_replace('\'', '\'\'', $this->toTable->getComment())); 392 | } 393 | 394 | $alterScripts = []; 395 | 396 | if (!empty($tableDrops)) { 397 | $alterScripts[] = sprintf('ALTER TABLE `%s`%s %s;', $this->getName(), PHP_EOL, implode(',' . PHP_EOL . ' ', $tableDrops)); 398 | } 399 | 400 | if (!empty($tableChanges)) { 401 | $alterScripts[] = sprintf('ALTER TABLE `%s`%s %s;', $this->getName(), PHP_EOL, implode(',' . PHP_EOL . ' ', $tableChanges)); 402 | } 403 | 404 | return implode(PHP_EOL, $alterScripts); 405 | } 406 | 407 | /** 408 | * @param Column $column 409 | * 410 | * @return string 411 | */ 412 | private function getAfterClause(Column $column) 413 | { 414 | if ($column->getPreviousColumn() instanceof Column) { 415 | return sprintf('AFTER `%s`', $column->getPreviousColumn()->getName()); 416 | } 417 | 418 | return 'FIRST'; 419 | } 420 | } 421 | -------------------------------------------------------------------------------- /src/Model/Table.php: -------------------------------------------------------------------------------- 1 | name = $name; 86 | } 87 | 88 | /** 89 | * @return string 90 | */ 91 | public function getName() 92 | { 93 | return $this->name; 94 | } 95 | 96 | /** 97 | * @return bool 98 | */ 99 | public function isIfNotExists() 100 | { 101 | return $this->ifNotExists; 102 | } 103 | 104 | /** 105 | * @param bool $ifNotExists 106 | */ 107 | public function setIfNotExists($ifNotExists) 108 | { 109 | $this->ifNotExists = $ifNotExists; 110 | } 111 | 112 | /** 113 | * @return string 114 | */ 115 | public function getDefinition() 116 | { 117 | return $this->definition; 118 | } 119 | 120 | /** 121 | * @param string $definition 122 | */ 123 | public function setDefinition($definition) 124 | { 125 | $this->definition = $definition; 126 | } 127 | 128 | /** 129 | * @return string 130 | */ 131 | public function getCreationScript() 132 | { 133 | return $this->creationScript; 134 | } 135 | 136 | /** 137 | * @param string $creationScript 138 | */ 139 | public function setCreationScript($creationScript) 140 | { 141 | $this->creationScript = $creationScript; 142 | } 143 | 144 | /** 145 | * @return Column[] 146 | */ 147 | public function getColumns() 148 | { 149 | return $this->columns; 150 | } 151 | 152 | /** 153 | * @param Column[] $columns 154 | */ 155 | public function setColumns($columns) 156 | { 157 | $this->columns = $columns; 158 | } 159 | 160 | /** 161 | * @param Column $column 162 | */ 163 | public function addColumn(Column $column) 164 | { 165 | $column->setParentTable($this); 166 | $this->columns[$column->getName()] = $column; 167 | } 168 | 169 | /** 170 | * @param string $columnName 171 | * 172 | * @throws \RuntimeException 173 | * 174 | * @return Column 175 | */ 176 | public function getColumnByName($columnName) 177 | { 178 | if (!isset($this->columns[$columnName])) { 179 | throw new \RuntimeException(sprintf('Column "%s" not found in table "%s"!', $columnName, $this->name)); 180 | } 181 | 182 | return $this->columns[$columnName]; 183 | } 184 | 185 | /** 186 | * @param int $columnOrder 187 | * 188 | * @throws \RuntimeException 189 | * 190 | * @return Column 191 | */ 192 | public function getColumnByOrder($columnOrder) 193 | { 194 | foreach ($this->columns as $column) { 195 | if ($column->getOrder() === $columnOrder) { 196 | return $column; 197 | } 198 | } 199 | 200 | throw new \RuntimeException(sprintf('Column order "%s" not found in table "%s"!', $columnOrder, $this->name)); 201 | } 202 | 203 | /** 204 | * @param string $columnName 205 | * 206 | * @return bool 207 | */ 208 | public function hasColumn($columnName) 209 | { 210 | return isset($this->columns[$columnName]); 211 | } 212 | 213 | /** 214 | * @return Column[] 215 | */ 216 | public function getPrimaryKeys() 217 | { 218 | return $this->primaryKeys; 219 | } 220 | 221 | /** 222 | * @param Column $primaryKeyColumn 223 | */ 224 | public function addPrimaryKey(Column $primaryKeyColumn) 225 | { 226 | $this->primaryKeys[] = $primaryKeyColumn; 227 | } 228 | 229 | /** 230 | * @return ForeignKey[] 231 | */ 232 | public function getForeignKeys() 233 | { 234 | return $this->foreignKeys; 235 | } 236 | 237 | /** 238 | * @param ForeignKey $foreignKey 239 | */ 240 | public function addForeignKey(ForeignKey $foreignKey) 241 | { 242 | $foreignKey->setParentTable($this); 243 | $this->foreignKeys[$foreignKey->getName()] = $foreignKey; 244 | } 245 | 246 | /** 247 | * @param string $foreignKeyName 248 | * 249 | * @throws \RuntimeException 250 | * 251 | * @return ForeignKey 252 | */ 253 | public function getForeignKeyByName($foreignKeyName) 254 | { 255 | if (!isset($this->foreignKeys[$foreignKeyName])) { 256 | throw new \RuntimeException(sprintf('Foreign key "%s" not found in table "%s"!', $foreignKeyName, $this->name)); 257 | } 258 | 259 | return $this->foreignKeys[$foreignKeyName]; 260 | } 261 | 262 | /** 263 | * @param string $foreignKeyName 264 | * 265 | * @return bool 266 | */ 267 | public function hasForeignKey($foreignKeyName) 268 | { 269 | return isset($this->foreignKeys[$foreignKeyName]); 270 | } 271 | 272 | /** 273 | * @return Index[] 274 | */ 275 | public function getIndexes() 276 | { 277 | return $this->indexes; 278 | } 279 | 280 | /** 281 | * @param Index $index 282 | */ 283 | public function addIndex(Index $index) 284 | { 285 | $index->setParentTable($this); 286 | $this->indexes[$index->getName()] = $index; 287 | } 288 | 289 | /** 290 | * @param string $indexName 291 | * 292 | * @throws \RuntimeException 293 | * 294 | * @return Index 295 | */ 296 | public function getIndexByName($indexName) 297 | { 298 | if (!isset($this->indexes[$indexName])) { 299 | throw new \RuntimeException(sprintf('Index "%s" not found in table "%s"!', $indexName, $this->name)); 300 | } 301 | 302 | return $this->indexes[$indexName]; 303 | } 304 | 305 | /** 306 | * @param string $indexName 307 | * 308 | * @return bool 309 | */ 310 | public function hasIndex($indexName) 311 | { 312 | return isset($this->indexes[$indexName]); 313 | } 314 | 315 | /** 316 | * @return string 317 | */ 318 | public function getEngine() 319 | { 320 | return $this->engine; 321 | } 322 | 323 | /** 324 | * @param string $engine 325 | */ 326 | public function setEngine($engine) 327 | { 328 | $this->engine = $engine; 329 | } 330 | 331 | /** 332 | * @return string 333 | */ 334 | public function getRowFormat() 335 | { 336 | return $this->rowFormat; 337 | } 338 | 339 | /** 340 | * @param string $rowFormat 341 | */ 342 | public function setRowFormat($rowFormat) 343 | { 344 | $this->rowFormat = $rowFormat; 345 | } 346 | 347 | /** 348 | * @return string 349 | */ 350 | public function getKeyBlockSize() 351 | { 352 | return $this->keyBlockSize; 353 | } 354 | 355 | /** 356 | * @param string $keyBlockSize 357 | */ 358 | public function setKeyBlockSize($keyBlockSize) 359 | { 360 | $this->keyBlockSize = $keyBlockSize; 361 | } 362 | 363 | /** 364 | * @return int 365 | */ 366 | public function getAutoIncrement() 367 | { 368 | return $this->autoIncrement; 369 | } 370 | 371 | /** 372 | * @param int $autoIncrement 373 | */ 374 | public function setAutoIncrement($autoIncrement) 375 | { 376 | $this->autoIncrement = $autoIncrement; 377 | } 378 | 379 | /** 380 | * @return string 381 | */ 382 | public function getDefaultCharset() 383 | { 384 | return $this->defaultCharset; 385 | } 386 | 387 | /** 388 | * @param string $defaultCharset 389 | */ 390 | public function setDefaultCharset($defaultCharset) 391 | { 392 | $this->defaultCharset = $defaultCharset; 393 | } 394 | 395 | /** 396 | * @return string 397 | */ 398 | public function getComment() 399 | { 400 | return $this->comment; 401 | } 402 | 403 | /** 404 | * @param string $comment 405 | */ 406 | public function setComment($comment) 407 | { 408 | $this->comment = $comment; 409 | } 410 | 411 | /** 412 | * @return string 413 | */ 414 | public function generatePrimaryKeyCreationScript() 415 | { 416 | if (empty($this->primaryKeys)) { 417 | return ''; 418 | } 419 | 420 | $primaryKeys = []; 421 | foreach ($this->primaryKeys as $primaryKeyColumn) { 422 | if ($primaryKeyColumn->getPrimaryKeyLength()) { 423 | $primaryKey = sprintf('`%s`(%s)', $primaryKeyColumn->getName(), $primaryKeyColumn->getPrimaryKeyLength()); 424 | } else { 425 | $primaryKey = sprintf('`%s`', $primaryKeyColumn->getName()); 426 | } 427 | 428 | $primaryKeys[] = $primaryKey; 429 | } 430 | 431 | return sprintf('PRIMARY KEY (%s)', implode(',', $primaryKeys)); 432 | } 433 | 434 | /** 435 | * @param bool $ignoreAutoIncrement 436 | * @param bool $sortKeys 437 | * 438 | * @return string 439 | */ 440 | public function generateCreationScript($ignoreAutoIncrement = false, $sortKeys = true) 441 | { 442 | $tableDefinitions = []; 443 | 444 | // Columns 445 | foreach ($this->columns as $column) { 446 | $tableDefinitions[] = $column->generateCreationScript(); 447 | } 448 | 449 | // Primary Keys 450 | if (!empty($this->primaryKeys)) { 451 | $tableDefinitions[] = $this->generatePrimaryKeyCreationScript(); 452 | } 453 | 454 | // Indexes 455 | if ($sortKeys) { 456 | ksort($this->indexes); 457 | } 458 | 459 | foreach ($this->indexes as $index) { 460 | $tableDefinitions[] = $index->generateCreationScript(); 461 | } 462 | 463 | // Foreign Keys 464 | if ($sortKeys) { 465 | ksort($this->foreignKeys); 466 | } 467 | 468 | foreach ($this->foreignKeys as $foreignKey) { 469 | $tableDefinitions[] = $foreignKey->generateCreationScript(); 470 | } 471 | 472 | $tableOptions = []; 473 | 474 | if ($this->ifNotExists) { 475 | $ifNotExists = ' IF NOT EXISTS'; 476 | } else { 477 | $ifNotExists = ''; 478 | } 479 | 480 | if ($this->engine) { 481 | $tableOptions[] = sprintf('ENGINE=%s', $this->engine); 482 | } 483 | 484 | if ($this->autoIncrement && !$ignoreAutoIncrement) { 485 | $tableOptions[] = sprintf('AUTO_INCREMENT=%s', $this->autoIncrement); 486 | } 487 | 488 | if ($this->defaultCharset) { 489 | $tableOptions[] = sprintf('DEFAULT CHARSET=%s', $this->defaultCharset); 490 | } 491 | 492 | if ($this->rowFormat) { 493 | $tableOptions[] = sprintf('ROW_FORMAT=%s', $this->rowFormat); 494 | } 495 | 496 | if ($this->keyBlockSize) { 497 | $tableOptions[] = sprintf('KEY_BLOCK_SIZE=%s', $this->keyBlockSize); 498 | } 499 | 500 | if ($this->comment) { 501 | $tableOptions[] = sprintf('COMMENT=\'%s\'', str_replace('\'', '\'\'', $this->comment)); 502 | } 503 | 504 | $implodedTableOptions = implode(' ', $tableOptions); 505 | 506 | if (!empty($implodedTableOptions)) { 507 | $implodedTableOptions = ' ' . $implodedTableOptions; 508 | } 509 | 510 | return trim(sprintf('CREATE TABLE%s `%s` (%s %s%s)%s;', $ifNotExists, $this->name, PHP_EOL, implode(',' . PHP_EOL . ' ', $tableDefinitions), PHP_EOL, $implodedTableOptions)); 511 | } 512 | } 513 | -------------------------------------------------------------------------------- /src/Parser.php: -------------------------------------------------------------------------------- 1 | parseTables($this->convertStringsToBase64($sqlScript)); 27 | 28 | foreach ($tables as $table) { 29 | $this->parseTableDefinition($table); 30 | 31 | $database->addTable($table); 32 | } 33 | 34 | return $database; 35 | } 36 | 37 | /** 38 | * @param string $sqlScript 39 | * 40 | * @return Table[] 41 | */ 42 | public function parseTables($sqlScript) 43 | { 44 | preg_match_all(RegExpPattern::tables(), $sqlScript, $matches); 45 | 46 | $tables = []; 47 | $loopCounter = count($matches[0]); 48 | for ($i = 0; $i < $loopCounter; $i++) { 49 | $name = $matches['tableName'][$i]; 50 | $ifNotExists = $matches['ifNotExists'][$i]; 51 | $definition = $this->convertStringsFromBase64($matches['tableDefinition'][$i]); 52 | $creationScript = $this->convertStringsFromBase64($matches['creationScript'][$i]); 53 | $engine = $matches['engine'][$i]; 54 | $autoIncrement = $matches['autoIncrement'][$i]; 55 | $defaultCharset = $matches['defaultCharset'][$i]; 56 | $comment = base64_decode($matches['comment'][$i]); 57 | $rowFormat = $matches['rowFormat'][$i]; 58 | $keyBlockSize = $matches['keyBlockSize'][$i]; 59 | 60 | $table = new Table($name); 61 | $table->setDefinition(trim($definition)); 62 | $table->setCreationScript(trim($creationScript) . ';'); 63 | 64 | if ($ifNotExists) { 65 | $table->setIfNotExists(true); 66 | } 67 | 68 | if ($engine) { 69 | $table->setEngine($engine); 70 | } 71 | 72 | if ($autoIncrement) { 73 | $table->setAutoIncrement((int) $autoIncrement); 74 | } 75 | 76 | if ($defaultCharset) { 77 | $table->setDefaultCharset($defaultCharset); 78 | } 79 | 80 | if ($comment) { 81 | $table->setComment(str_replace('\'\'', '\'', $comment)); 82 | } 83 | 84 | if ($rowFormat) { 85 | $table->setRowFormat($rowFormat); 86 | } 87 | 88 | if ($keyBlockSize) { 89 | $table->setKeyBlockSize($keyBlockSize); 90 | } 91 | 92 | $tables[$name] = $table; 93 | } 94 | 95 | return $tables; 96 | } 97 | 98 | /** 99 | * @param Table $table 100 | */ 101 | public function parseTableDefinition(Table $table) 102 | { 103 | $this->parseColumns($table); 104 | $this->parsePrimaryKey($table); 105 | $this->parseForeignKeys($table); 106 | $this->parseIndexes($table); 107 | } 108 | 109 | /** 110 | * @param Table $table 111 | */ 112 | public function parseColumns(Table $table) 113 | { 114 | preg_match_all(RegExpPattern::column(), $table->getDefinition(), $matches); 115 | 116 | $lastColumn = null; 117 | $loopCounter = count($matches[0]); 118 | for ($i = 0; $i < $loopCounter; $i++) { 119 | $columnName = $matches['columnName'][$i]; 120 | $columnType = $matches['columnType'][$i]; 121 | $intLength = $matches['intLength'][$i]; 122 | $decimalLength = $matches['decimalLength'][$i]; 123 | $doubleLength = $matches['doubleLength'][$i]; 124 | $floatLength = $matches['floatLength'][$i]; 125 | $charLength = $matches['charLength'][$i]; 126 | $binaryLength = $matches['binaryLength'][$i]; 127 | $yearLength = $matches['yearLength'][$i]; 128 | $decimalPrecision = $matches['decimalPrecision'][$i]; 129 | $doublePrecision = $matches['doublePrecision'][$i]; 130 | $floatPrecision = $matches['floatPrecision'][$i]; 131 | $fractionalSeconds = $matches['fractionalSeconds'][$i]; 132 | $nullable = $matches['nullable'][$i]; 133 | $autoIncrement = $matches['autoIncrement'][$i]; 134 | $defaultValue = $matches['defaultValue'][$i]; 135 | $onUpdateValue = $matches['onUpdateValue'][$i]; 136 | $comment = $matches['comment'][$i]; 137 | $characterSet = $matches['characterSet'][$i]; 138 | $collate = $matches['collate'][$i]; 139 | 140 | $column = new Column($columnName); 141 | $column->setColumnType($columnType); 142 | 143 | preg_match(RegExpPattern::dataType(), $columnType, $dataTypeMatches); 144 | $dataType = $dataTypeMatches['dataType']; 145 | $unsigned = isset($dataTypeMatches['unsigned']) && !empty($dataTypeMatches['unsigned']); 146 | $column->setDataType($dataType); 147 | $column->setUnsigned($unsigned); 148 | 149 | $column->setLength($this->getColumnLength($intLength, $decimalLength, $doubleLength, $floatLength, $charLength, $binaryLength, $yearLength, $fractionalSeconds)); 150 | $column->setPrecision($this->getColumnPrecision($decimalPrecision, $doublePrecision, $floatPrecision)); 151 | $column->setNullable($nullable !== 'NOT NULL'); 152 | $column->setAutoIncrement(!empty($autoIncrement)); 153 | 154 | if (!empty($defaultValue)) { 155 | $column->setDefaultValue($defaultValue); 156 | } 157 | 158 | if (!empty($onUpdateValue)) { 159 | $column->setOnUpdateValue($onUpdateValue); 160 | } 161 | 162 | if (!empty($comment)) { 163 | $column->setComment(str_replace('\'\'', '\'', $comment)); 164 | } 165 | 166 | if (!empty($characterSet)) { 167 | $column->setCharacterSet($characterSet); 168 | } 169 | 170 | if (!empty($collate)) { 171 | $column->setCollate($collate); 172 | } 173 | 174 | $column->setPrimaryKey(false); 175 | 176 | if ($lastColumn instanceof Column) { 177 | $column->setPreviousColumn($lastColumn); 178 | $lastColumn->setNextColumn($column); 179 | } 180 | 181 | $column->setOrder($i); 182 | 183 | $table->addColumn($column); 184 | $lastColumn = $column; 185 | } 186 | } 187 | 188 | /** 189 | * @param Table $table 190 | */ 191 | public function parsePrimaryKey(Table $table) 192 | { 193 | if (preg_match(RegExpPattern::primaryKey(), $table->getDefinition(), $matches) !== 1) { 194 | return; 195 | } 196 | 197 | $primaryKeyNames = explode(',', str_replace('`', '', $matches['primaryKey'])); 198 | 199 | foreach ($primaryKeyNames as $primaryKeyName) { 200 | if (preg_match('/^(?[^\(]+)\((?\d+)\)/', $primaryKeyName, $keyMatches)) { 201 | $columnName = $keyMatches['columnName']; 202 | $keyLength = $keyMatches['keyLength']; 203 | } else { 204 | $columnName = $primaryKeyName; 205 | $keyLength = null; 206 | } 207 | $primaryKeyColumn = $table->getColumnByName(trim($columnName)); 208 | $primaryKeyColumn->setPrimaryKey(true); 209 | 210 | if ($keyLength) { 211 | $primaryKeyColumn->setPrimaryKeyLength($keyLength); 212 | } 213 | 214 | $table->addPrimaryKey($primaryKeyColumn); 215 | } 216 | } 217 | 218 | /** 219 | * @param Table $table 220 | */ 221 | public function parseForeignKeys(Table $table) 222 | { 223 | preg_match_all(RegExpPattern::foreignKey(), $table->getDefinition(), $matches); 224 | 225 | $loopCounter = count($matches[0]); 226 | for ($i = 0; $i < $loopCounter; $i++) { 227 | $name = $matches['name'][$i]; 228 | $columnName = $matches['column'][$i]; 229 | $referenceTableName = $matches['referenceTable'][$i]; 230 | $referenceColumnName = $matches['referenceColumn'][$i]; 231 | $onDeleteClause = $matches['onDelete'][$i]; 232 | $onUpdateClause = $matches['onUpdate'][$i]; 233 | 234 | $foreignKey = new ForeignKey($name); 235 | $foreignKey->setColumnName($columnName); 236 | $foreignKey->setReferenceTableName($referenceTableName); 237 | $foreignKey->setReferenceColumnName($referenceColumnName); 238 | 239 | if (!empty($onDeleteClause)) { 240 | $foreignKey->setOnDeleteClause($onDeleteClause); 241 | } 242 | 243 | if (!empty($onUpdateClause)) { 244 | $foreignKey->setOnUpdateClause($onUpdateClause); 245 | } 246 | 247 | $table->addForeignKey($foreignKey); 248 | } 249 | } 250 | 251 | /** 252 | * @param Table $table 253 | */ 254 | public function parseIndexes(Table $table) 255 | { 256 | preg_match_all(RegExpPattern::index(), $table->getDefinition(), $matches); 257 | 258 | $loopCounter = count($matches[0]); 259 | for ($i = 0; $i < $loopCounter; $i++) { 260 | $indexName = $matches['name'][$i]; 261 | $indexColumnNames = explode(',', str_replace('`', '', $matches['columns'][$i])); 262 | $indexOptions = $matches['options'][$i]; 263 | $spatial = $matches['spatial'][$i]; 264 | $unique = $matches['unique'][$i]; 265 | $fullText = $matches['fullText'][$i]; 266 | 267 | $index = new Index($indexName); 268 | 269 | foreach ($indexColumnNames as $indexColumnDefinition) { 270 | preg_match(RegExpPattern::indexColumn(), $indexColumnDefinition, $definitionMatch); 271 | 272 | $indexColumnName = $definitionMatch['columnName']; 273 | 274 | $indexFirstCharacters = null; 275 | if (isset($definitionMatch['firstCharacters']) && !empty($definitionMatch['firstCharacters'])) { 276 | $indexFirstCharacters = (int) $definitionMatch['firstCharacters']; 277 | } 278 | 279 | $column = $table->getColumnByName(trim($indexColumnName)); 280 | $index->addIndexColumn(new IndexColumn($column, $indexFirstCharacters)); 281 | } 282 | 283 | $index->setUnique(!empty($unique)); 284 | $index->setSpatial(!empty($spatial)); 285 | $index->setFulltext(!empty($fullText)); 286 | 287 | if (!empty($indexOptions)) { 288 | $index->setOptions(trim($indexOptions)); 289 | } 290 | 291 | $table->addIndex($index); 292 | } 293 | } 294 | 295 | /** 296 | * @param int $intLength 297 | * @param int $decimalLength 298 | * @param int $doubleLength 299 | * @param int $floatLength 300 | * @param int $charLength 301 | * @param int $binaryLength 302 | * @param int $yearLength 303 | * @param int $fractionalSeconds 304 | * 305 | * @return int|null 306 | */ 307 | private function getColumnLength($intLength, $decimalLength, $doubleLength, $floatLength, $charLength, $binaryLength, $yearLength, $fractionalSeconds) 308 | { 309 | if (!empty($intLength)) { 310 | return (int) $intLength; 311 | } 312 | if (!empty($decimalLength)) { 313 | return (int) $decimalLength; 314 | } 315 | if (!empty($doubleLength)) { 316 | return (int) $doubleLength; 317 | } 318 | if (!empty($floatLength)) { 319 | return (int) $floatLength; 320 | } 321 | if (!empty($charLength)) { 322 | return (int) $charLength; 323 | } 324 | if (!empty($binaryLength)) { 325 | return (int) $binaryLength; 326 | } 327 | if (!empty($yearLength)) { 328 | return (int) $yearLength; 329 | } 330 | if (!empty($fractionalSeconds)) { 331 | return (int) $fractionalSeconds; 332 | } 333 | 334 | return; 335 | } 336 | 337 | /** 338 | * @param int $decimalPrecision 339 | * @param int $doublePrecision 340 | * @param int $floatPrecision 341 | * 342 | * @return int|null 343 | */ 344 | private function getColumnPrecision($decimalPrecision, $doublePrecision, $floatPrecision) 345 | { 346 | if (!empty($decimalPrecision)) { 347 | return (int) $decimalPrecision; 348 | } 349 | if (!empty($doublePrecision)) { 350 | return (int) $doublePrecision; 351 | } 352 | if (!empty($floatPrecision)) { 353 | return (int) $floatPrecision; 354 | } 355 | 356 | return; 357 | } 358 | 359 | public function convertStringsToBase64($sqlScript) 360 | { 361 | $sqlScript = preg_replace_callback('/DEFAULT\s*\'(?[^\']+)\'/', function ($matches) { 362 | return sprintf('DEFAULT \'%s\'', base64_encode($matches['defaultValue'])); 363 | }, $sqlScript); 364 | 365 | $sqlScript = preg_replace_callback('/COMMENT\s*\'(?[^\']+)\'/', function ($matches) { 366 | return sprintf('COMMENT \'%s\'', base64_encode($matches['comment'])); 367 | }, $sqlScript); 368 | 369 | $sqlScript = preg_replace_callback('/COMMENT\s*=\s*\'(?([^\']|\'\')+)\'/', function ($matches) { 370 | return sprintf('COMMENT=\'%s\'', base64_encode($matches['comment'])); 371 | }, $sqlScript); 372 | 373 | return $sqlScript; 374 | } 375 | 376 | public function convertStringsFromBase64($sqlScript) 377 | { 378 | $sqlScript = preg_replace_callback('/DEFAULT\s*\'(?[^\']+)\'/', function ($matches) { 379 | return sprintf('DEFAULT \'%s\'', base64_decode($matches['defaultValue'])); 380 | }, $sqlScript); 381 | 382 | $sqlScript = preg_replace_callback('/COMMENT\s*\'(?[^\']+)\'/', function ($matches) { 383 | return sprintf('COMMENT \'%s\'', base64_decode($matches['comment'])); 384 | }, $sqlScript); 385 | 386 | $sqlScript = preg_replace_callback('/COMMENT\s*=\s*\'(?([^\']|\'\')+)\'/', function ($matches) { 387 | return sprintf('COMMENT=\'%s\'', base64_decode($matches['comment'])); 388 | }, $sqlScript); 389 | 390 | return $sqlScript; 391 | } 392 | } 393 | -------------------------------------------------------------------------------- /tests/ParserTest.php: -------------------------------------------------------------------------------- 1 | parseTables($this->getDatabaseFixture('sakila.sql')); 19 | 20 | $this->assertCount(19, $result); 21 | $this->assertArrayHasKey('actor', $result); 22 | $this->assertInstanceOf(Table::class, $result['actor']); 23 | $this->assertEquals('actor', $result['actor']->getName()); 24 | $this->assertEquals('InnoDB', $result['actor']->getEngine()); 25 | $this->assertEquals(201, $result['actor']->getAutoIncrement()); 26 | $this->assertEquals('utf8', $result['actor']->getDefaultCharset()); 27 | $this->assertEquals($this->getDatabaseFixture('actor.sql'), $result['actor']->getCreationScript()); 28 | $this->assertEquals($this->getDatabaseFixture('actor_definition.sql'), $result['actor']->getDefinition()); 29 | } 30 | 31 | public function testIsParsingColumns() 32 | { 33 | $parser = new Parser(); 34 | 35 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 36 | $actorTable = $tables['actor']; 37 | 38 | $parser->parseColumns($actorTable); 39 | 40 | $this->assertCount(4, $actorTable->getColumns()); 41 | 42 | $this->assertArrayHasKey('actor_id', $actorTable->getColumns()); 43 | $this->assertInstanceOf(Column::class, $actorTable->getColumnByName('actor_id')); 44 | $this->assertEquals('actor_id', $actorTable->getColumnByName('actor_id')->getName()); 45 | $this->assertEquals('smallint(5) unsigned', $actorTable->getColumnByName('actor_id')->getColumnType()); 46 | $this->assertEquals('smallint', $actorTable->getColumnByName('actor_id')->getDataType()); 47 | $this->assertTrue($actorTable->getColumnByName('actor_id')->isUnsigned()); 48 | $this->assertEquals(5 , $actorTable->getColumnByName('actor_id')->getLength()); 49 | $this->assertNull($actorTable->getColumnByName('actor_id')->getPrecision()); 50 | $this->assertFalse($actorTable->getColumnByName('actor_id')->isNullable()); 51 | $this->assertTrue($actorTable->getColumnByName('actor_id')->isAutoIncrement()); 52 | $this->assertFalse($actorTable->getColumnByName('actor_id')->isPrimaryKey()); 53 | $this->assertNull($actorTable->getColumnByName('actor_id')->getDefaultValue()); 54 | $this->assertNull($actorTable->getColumnByName('actor_id')->getOnUpdateValue()); 55 | $this->assertNull($actorTable->getColumnByName('actor_id')->getCharacterSet()); 56 | $this->assertNull($actorTable->getColumnByName('actor_id')->getCollate()); 57 | 58 | $this->assertArrayHasKey('last_update', $actorTable->getColumns()); 59 | $this->assertInstanceOf(Column::class, $actorTable->getColumnByName('last_update')); 60 | $this->assertEquals('last_update', $actorTable->getColumnByName('last_update')->getName()); 61 | $this->assertEquals('timestamp', $actorTable->getColumnByName('last_update')->getColumnType()); 62 | $this->assertEquals('timestamp', $actorTable->getColumnByName('last_update')->getDataType()); 63 | $this->assertFalse($actorTable->getColumnByName('last_update')->isUnsigned()); 64 | $this->assertNull($actorTable->getColumnByName('last_update')->getLength()); 65 | $this->assertNull($actorTable->getColumnByName('last_update')->getPrecision()); 66 | $this->assertFalse($actorTable->getColumnByName('last_update')->isNullable()); 67 | $this->assertFalse($actorTable->getColumnByName('last_update')->isAutoIncrement()); 68 | $this->assertFalse($actorTable->getColumnByName('last_update')->isPrimaryKey()); 69 | $this->assertEquals('CURRENT_TIMESTAMP', $actorTable->getColumnByName('last_update')->getDefaultValue()); 70 | $this->assertEquals('CURRENT_TIMESTAMP', $actorTable->getColumnByName('last_update')->getOnUpdateValue()); 71 | $this->assertNull($actorTable->getColumnByName('last_update')->getCharacterSet()); 72 | $this->assertNull($actorTable->getColumnByName('last_update')->getCollate()); 73 | } 74 | 75 | public function testIsParsingColumnWithDefaultCharacterSetAndCollate() 76 | { 77 | $parser = new Parser(); 78 | 79 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 80 | $staffTable = $tables['staff']; 81 | 82 | $parser->parseColumns($staffTable); 83 | 84 | $this->assertCount(11, $staffTable->getColumns()); 85 | 86 | $this->assertArrayHasKey('password', $staffTable->getColumns()); 87 | $this->assertInstanceOf(Column::class, $staffTable->getColumnByName('password')); 88 | $this->assertEquals('password', $staffTable->getColumnByName('password')->getName()); 89 | $this->assertEquals('varchar(40)', $staffTable->getColumnByName('password')->getColumnType()); 90 | $this->assertEquals('varchar', $staffTable->getColumnByName('password')->getDataType()); 91 | $this->assertFalse($staffTable->getColumnByName('password')->isUnsigned()); 92 | $this->assertEquals(40 , $staffTable->getColumnByName('password')->getLength()); 93 | $this->assertNull($staffTable->getColumnByName('password')->getPrecision()); 94 | $this->assertTrue($staffTable->getColumnByName('password')->isNullable()); 95 | $this->assertFalse($staffTable->getColumnByName('password')->isAutoIncrement()); 96 | $this->assertFalse($staffTable->getColumnByName('password')->isPrimaryKey()); 97 | $this->assertEquals('NULL', $staffTable->getColumnByName('password')->getDefaultValue()); 98 | $this->assertNull($staffTable->getColumnByName('password')->getOnUpdateValue()); 99 | $this->assertEquals('utf8', $staffTable->getColumnByName('password')->getCharacterSet()); 100 | $this->assertEquals('utf8_bin', $staffTable->getColumnByName('password')->getCollate()); 101 | } 102 | 103 | public function testIsParsingColumnsInTableWithNoPrimaryKey() 104 | { 105 | $parser = new Parser(); 106 | 107 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 108 | $testTable = $tables['test']; 109 | 110 | $parser->parseColumns($testTable); 111 | 112 | $this->assertCount(1, $testTable->getColumns()); 113 | 114 | $this->assertArrayHasKey('test1', $testTable->getColumns()); 115 | $this->assertInstanceOf(Column::class, $testTable->getColumnByName('test1')); 116 | $this->assertEquals('test1', $testTable->getColumnByName('test1')->getName()); 117 | $this->assertEquals('int(10)', $testTable->getColumnByName('test1')->getColumnType()); 118 | $this->assertEquals('int', $testTable->getColumnByName('test1')->getDataType()); 119 | $this->assertFalse($testTable->getColumnByName('test1')->isUnsigned()); 120 | $this->assertEquals(10 , $testTable->getColumnByName('test1')->getLength()); 121 | $this->assertNull($testTable->getColumnByName('test1')->getPrecision()); 122 | $this->assertTrue($testTable->getColumnByName('test1')->isNullable()); 123 | $this->assertFalse($testTable->getColumnByName('test1')->isAutoIncrement()); 124 | $this->assertFalse($testTable->getColumnByName('test1')->isPrimaryKey()); 125 | $this->assertEquals('NULL', $testTable->getColumnByName('test1')->getDefaultValue()); 126 | $this->assertNull($testTable->getColumnByName('test1')->getOnUpdateValue()); 127 | } 128 | 129 | public function testIsParsingPrimaryKey() 130 | { 131 | $parser = new Parser(); 132 | 133 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 134 | $actorTable = $tables['actor']; 135 | 136 | $parser->parseColumns($actorTable); 137 | $parser->parsePrimaryKey($actorTable); 138 | 139 | $this->assertCount(1, $actorTable->getPrimaryKeys()); 140 | $this->assertInstanceOf(Column::class, $actorTable->getPrimaryKeys()[0]); 141 | $this->assertEquals('actor_id', $actorTable->getPrimaryKeys()[0]->getName()); 142 | $this->assertTrue($actorTable->getPrimaryKeys()[0]->isPrimaryKey()); 143 | } 144 | 145 | public function testIsParsingPrimaryKeyInTableWithNoIndexes() 146 | { 147 | $parser = new Parser(); 148 | 149 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 150 | $countryTable = $tables['country']; 151 | 152 | $parser->parseColumns($countryTable); 153 | $parser->parsePrimaryKey($countryTable); 154 | 155 | $this->assertCount(1, $countryTable->getPrimaryKeys()); 156 | $this->assertInstanceOf(Column::class, $countryTable->getPrimaryKeys()[0]); 157 | $this->assertEquals('country_id', $countryTable->getPrimaryKeys()[0]->getName()); 158 | $this->assertTrue($countryTable->getPrimaryKeys()[0]->isPrimaryKey()); 159 | } 160 | 161 | public function testIsParsingMultiplePrimaryKeys() 162 | { 163 | $parser = new Parser(); 164 | 165 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 166 | $filmCategoryTable = $tables['film_category']; 167 | 168 | $parser->parseColumns($filmCategoryTable); 169 | $parser->parsePrimaryKey($filmCategoryTable); 170 | 171 | $this->assertCount(2, $filmCategoryTable->getPrimaryKeys()); 172 | $this->assertInstanceOf(Column::class, $filmCategoryTable->getPrimaryKeys()[0]); 173 | $this->assertEquals('film_id', $filmCategoryTable->getPrimaryKeys()[0]->getName()); 174 | $this->assertTrue($filmCategoryTable->getPrimaryKeys()[0]->isPrimaryKey()); 175 | $this->assertInstanceOf(Column::class, $filmCategoryTable->getPrimaryKeys()[1]); 176 | $this->assertEquals('category_id', $filmCategoryTable->getPrimaryKeys()[1]->getName()); 177 | $this->assertTrue($filmCategoryTable->getPrimaryKeys()[1]->isPrimaryKey()); 178 | } 179 | 180 | public function testIsParsingForeignKeys() 181 | { 182 | $parser = new Parser(); 183 | 184 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 185 | $staffTable = $tables['staff']; 186 | 187 | $parser->parseColumns($staffTable); 188 | $parser->parsePrimaryKey($staffTable); 189 | $parser->parseForeignKeys($staffTable); 190 | 191 | $this->assertCount(2, $staffTable->getForeignKeys()); 192 | 193 | $this->assertInstanceOf(ForeignKey::class, $staffTable->getForeignKeyByName('fk_staff_address')); 194 | $this->assertEquals('address_id', $staffTable->getForeignKeyByName('fk_staff_address')->getColumnName()); 195 | $this->assertEquals('address', $staffTable->getForeignKeyByName('fk_staff_address')->getReferenceTableName()); 196 | $this->assertEquals('address_id', $staffTable->getForeignKeyByName('fk_staff_address')->getReferenceColumnName()); 197 | $this->assertEquals('ON UPDATE CASCADE', $staffTable->getForeignKeyByName('fk_staff_address')->getOnUpdateClause()); 198 | } 199 | 200 | public function testIsParsingIndexes() 201 | { 202 | $parser = new Parser(); 203 | 204 | $tables = $parser->parseTables($this->getDatabaseFixture('sakila.sql')); 205 | $rentalTable = $tables['rental']; 206 | 207 | $parser->parseColumns($rentalTable); 208 | $parser->parsePrimaryKey($rentalTable); 209 | $parser->parseForeignKeys($rentalTable); 210 | $parser->parseIndexes($rentalTable); 211 | 212 | $this->assertCount(4, $rentalTable->getIndexes()); 213 | 214 | $this->assertInstanceOf(Index::class, $rentalTable->getIndexByName('rental_date')); 215 | $this->assertCount(3, $rentalTable->getIndexByName('rental_date')->getIndexColumns()); 216 | $this->assertInstanceOf(IndexColumn::class, $rentalTable->getIndexByName('rental_date')->getIndexColumnByColumnName('rental_date')); 217 | $this->assertInstanceOf(IndexColumn::class, $rentalTable->getIndexByName('rental_date')->getIndexColumnByColumnName('inventory_id')); 218 | $this->assertInstanceOf(IndexColumn::class, $rentalTable->getIndexByName('rental_date')->getIndexColumnByColumnName('customer_id')); 219 | $this->assertTrue($rentalTable->getIndexByName('rental_date')->isUnique()); 220 | $this->assertFalse($rentalTable->getIndexByName('rental_date')->isSpatial()); 221 | $this->assertFalse($rentalTable->getIndexByName('rental_date')->isFulltext()); 222 | $this->assertNull($rentalTable->getIndexByName('rental_date')->getOptions()); 223 | 224 | $this->assertInstanceOf(Index::class, $rentalTable->getIndexByName('idx_fk_staff_id')); 225 | $this->assertCount(1, $rentalTable->getIndexByName('idx_fk_staff_id')->getIndexColumns()); 226 | $this->assertInstanceOf(IndexColumn::class, $rentalTable->getIndexByName('idx_fk_staff_id')->getIndexColumnByColumnName('staff_id')); 227 | $this->assertFalse($rentalTable->getIndexByName('idx_fk_staff_id')->isUnique()); 228 | $this->assertFalse($rentalTable->getIndexByName('idx_fk_staff_id')->isSpatial()); 229 | $this->assertFalse($rentalTable->getIndexByName('idx_fk_staff_id')->isFulltext()); 230 | $this->assertNull($rentalTable->getIndexByName('idx_fk_staff_id')->getOptions()); 231 | } 232 | 233 | public function testIsParsingDatabase() 234 | { 235 | $parser = new Parser(); 236 | 237 | $database = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 238 | 239 | $this->assertInstanceOf(Database::class, $database); 240 | $this->assertCount(19, $database->getTables()); 241 | } 242 | 243 | public function testIsParsingTableComment() 244 | { 245 | $parser = new Parser(); 246 | 247 | $database = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 248 | 249 | $this->assertInstanceOf(Database::class, $database); 250 | $this->assertEquals('table\'s comment', $database->getTableByName('test')->getComment()); 251 | } 252 | 253 | public function testIsGeneratingTableCreationScript() 254 | { 255 | $parser = new Parser(); 256 | 257 | $database = $parser->parseDatabase($this->getDatabaseFixture('sakila.sql')); 258 | 259 | foreach ($database->getTables() as $table) { 260 | $this->assertEquals($table->getCreationScript(), $table->generateCreationScript(false, false)); 261 | } 262 | } 263 | 264 | public function testIsParsingTableWithPartitionDefinitions() 265 | { 266 | $parser = new Parser(); 267 | 268 | $database = $parser->parseDatabase($this->getDatabaseFixture('partition.sql')); 269 | 270 | $this->assertInstanceOf(Database::class, $database); 271 | $this->assertCount(1, $database->getTables()); 272 | $this->assertCount(9, $database->getTableByName('export')->getColumns()); 273 | } 274 | 275 | public function testIsParsingDoubleUnsignedType() 276 | { 277 | $parser = new Parser(); 278 | 279 | $database = $parser->parseDatabase($this->getDatabaseFixture('jos_finder_links.sql')); 280 | 281 | $this->assertInstanceOf(Database::class, $database); 282 | $this->assertCount(1, $database->getTables()); 283 | $this->assertCount(19, $database->getTableByName('jos_finder_links')->getColumns()); 284 | $this->assertEquals('double unsigned', $database->getTableByName('jos_finder_links')->getColumnByName('list_price')->getColumnType()); 285 | $this->assertEquals('double', $database->getTableByName('jos_finder_links')->getColumnByName('list_price')->getDataType()); 286 | } 287 | 288 | public function testIsParsingPrimaryKeyLength() 289 | { 290 | $creationScript = $this->getDatabaseFixture('jos_extwebdav_properties.sql'); 291 | 292 | $parser = new Parser(); 293 | 294 | $database = $parser->parseDatabase($creationScript); 295 | 296 | $this->assertInstanceOf(Database::class, $database); 297 | $this->assertCount(1, $database->getTables()); 298 | $this->assertCount(4, $database->getTableByName('jos_extwebdav_properties')->getColumns()); 299 | $this->assertCount(3, $database->getTableByName('jos_extwebdav_properties')->getPrimaryKeys()); 300 | 301 | $this->assertEquals($creationScript, $database->getTableByName('jos_extwebdav_properties')->generateCreationScript()); 302 | } 303 | 304 | public function testIsParsingCommentsWithSpecialCharacters() 305 | { 306 | $creationScript = $this->getDatabaseFixture('jos_ucm_history.sql'); 307 | 308 | $parser = new Parser(); 309 | 310 | $database = $parser->parseDatabase($creationScript); 311 | 312 | $this->assertInstanceOf(Database::class, $database); 313 | $this->assertCount(1, $database->getTables()); 314 | $this->assertCount(10, $database->getTableByName('jos_ucm_history')->getColumns()); 315 | $this->assertCount(1, $database->getTableByName('jos_ucm_history')->getPrimaryKeys()); 316 | $this->assertCount(2, $database->getTableByName('jos_ucm_history')->getIndexes()); 317 | $this->assertEquals(1, $database->getTableByName('jos_ucm_history')->getAutoIncrement()); 318 | $this->assertEquals('utf8', $database->getTableByName('jos_ucm_history')->getDefaultCharset()); 319 | $this->assertEquals('InnoDB', $database->getTableByName('jos_ucm_history')->getEngine()); 320 | $this->assertEquals('SHA1 hash of the version\'s data column.', $database->getTableByName('jos_ucm_history')->getColumnByName('sha1_hash')->getComment()); 321 | $this->assertEquals('`sha1_hash` varchar(50) NOT NULL DEFAULT \'\' COMMENT \'SHA1 hash of the version\'\'s data column.\'', $database->getTableByName('jos_ucm_history')->getColumnByName('sha1_hash')->generateCreationScript()); 322 | $this->assertEquals('0=auto delete; 1=keep', $database->getTableByName('jos_ucm_history')->getColumnByName('keep_forever')->getComment()); 323 | } 324 | 325 | public function testIsParsingCaseInsensitiveAndSpaces() 326 | { 327 | $creationScript = $this->getDatabaseFixture('jeff.sql'); 328 | 329 | $parser = new Parser(); 330 | 331 | $database = $parser->parseDatabase($creationScript); 332 | 333 | $this->assertInstanceOf(Database::class, $database); 334 | $this->assertCount(1, $database->getTables()); 335 | $this->assertCount(1, $database->getTableByName('contact')->getColumns()); 336 | $this->assertCount(0, $database->getTableByName('contact')->getPrimaryKeys()); 337 | $this->assertCount(0, $database->getTableByName('contact')->getIndexes()); 338 | $this->assertNull($database->getTableByName('contact')->getDefaultCharset()); 339 | $this->assertEquals('InnoDB', $database->getTableByName('contact')->getEngine()); 340 | $this->assertEquals('`id` BIGINT UNSIGNED NOT NULL AUTO_INCREMENT', $database->getTableByName('contact')->getColumnByName('id')->generateCreationScript()); 341 | } 342 | 343 | public function testIsParsingFractionalSeconds() 344 | { 345 | $creationScript = $this->getDatabaseFixture('fractional_seconds.sql'); 346 | 347 | $parser = new Parser(); 348 | 349 | $database = $parser->parseDatabase($creationScript); 350 | 351 | $this->assertInstanceOf(Database::class, $database); 352 | $this->assertCount(1, $database->getTables()); 353 | $this->assertCount(3, $database->getTableByName('fractional_seconds')->getColumns()); 354 | $this->assertCount(0, $database->getTableByName('fractional_seconds')->getPrimaryKeys()); 355 | $this->assertCount(0, $database->getTableByName('fractional_seconds')->getIndexes()); 356 | $this->assertNull($database->getTableByName('fractional_seconds')->getDefaultCharset()); 357 | $this->assertEquals('InnoDB', $database->getTableByName('fractional_seconds')->getEngine()); 358 | $this->assertEquals('`datetime_column` DATETIME(1) NOT NULL', $database->getTableByName('fractional_seconds')->getColumnByName('datetime_column')->generateCreationScript()); 359 | $this->assertEquals('`timestamp_column` TIMESTAMP(2) NOT NULL', $database->getTableByName('fractional_seconds')->getColumnByName('timestamp_column')->generateCreationScript()); 360 | $this->assertEquals('`time_column` TIME(3) NOT NULL', $database->getTableByName('fractional_seconds')->getColumnByName('time_column')->generateCreationScript()); 361 | } 362 | 363 | public function testIsParsingColumnWithBackslashInDefaultValue() 364 | { 365 | $creationScript = $this->getDatabaseFixture('backslash.sql'); 366 | 367 | $parser = new Parser(); 368 | 369 | $database = $parser->parseDatabase($creationScript); 370 | 371 | $this->assertInstanceOf(Database::class, $database); 372 | $this->assertCount(1, $database->getTables()); 373 | $this->assertCount(1, $database->getTableByName('backslash')->getColumns()); 374 | $this->assertCount(0, $database->getTableByName('backslash')->getPrimaryKeys()); 375 | $this->assertCount(0, $database->getTableByName('backslash')->getIndexes()); 376 | $this->assertEquals('utf8', $database->getTableByName('backslash')->getDefaultCharset()); 377 | $this->assertEquals('InnoDB', $database->getTableByName('backslash')->getEngine()); 378 | $this->assertEquals('Table/Comment', $database->getTableByName('backslash')->getComment()); 379 | $this->assertEquals('`time_zone` varchar(255) NOT NULL DEFAULT \'America/Los_Angeles\' COMMENT \'Column/Comment\'', $database->getTableByName('backslash')->getColumnByName('time_zone')->generateCreationScript()); 380 | } 381 | } 382 | -------------------------------------------------------------------------------- /tests/fixtures/sakila.sql: -------------------------------------------------------------------------------- 1 | -- MySQL dump 10.13 Distrib 5.7.10, for Win64 (x86_64) 2 | -- 3 | -- Host: localhost Database: sakila 4 | -- ------------------------------------------------------ 5 | -- Server version 5.7.10-log 6 | 7 | /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; 8 | /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; 9 | /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; 10 | /*!40101 SET NAMES utf8 */; 11 | /*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */; 12 | /*!40103 SET TIME_ZONE='+00:00' */; 13 | /*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */; 14 | /*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */; 15 | /*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */; 16 | /*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */; 17 | 18 | -- 19 | -- Table structure for table `actor` 20 | -- 21 | 22 | DROP TABLE IF EXISTS `actor`; 23 | /*!40101 SET @saved_cs_client = @@character_set_client */; 24 | /*!40101 SET character_set_client = utf8 */; 25 | CREATE TABLE `actor` ( 26 | `actor_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 27 | `first_name` varchar(45) NOT NULL, 28 | `last_name` varchar(45) NOT NULL, 29 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 30 | PRIMARY KEY (`actor_id`), 31 | KEY `idx_actor_last_name` (`last_name`) 32 | ) ENGINE=InnoDB AUTO_INCREMENT=201 DEFAULT CHARSET=utf8; 33 | /*!40101 SET character_set_client = @saved_cs_client */; 34 | 35 | -- 36 | -- Temporary view structure for view `actor_info` 37 | -- 38 | 39 | DROP TABLE IF EXISTS `actor_info`; 40 | /*!50001 DROP VIEW IF EXISTS `actor_info`*/; 41 | SET @saved_cs_client = @@character_set_client; 42 | SET character_set_client = utf8; 43 | /*!50001 CREATE VIEW `actor_info` AS SELECT 44 | 1 AS `actor_id`, 45 | 1 AS `first_name`, 46 | 1 AS `last_name`, 47 | 1 AS `film_info`*/; 48 | SET character_set_client = @saved_cs_client; 49 | 50 | -- 51 | -- Table structure for table `address` 52 | -- 53 | 54 | DROP TABLE IF EXISTS `address`; 55 | /*!40101 SET @saved_cs_client = @@character_set_client */; 56 | /*!40101 SET character_set_client = utf8 */; 57 | CREATE TABLE `address` ( 58 | `address_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 59 | `address` varchar(50) NOT NULL, 60 | `address2` varchar(50) DEFAULT NULL, 61 | `district` varchar(20) NOT NULL, 62 | `city_id` smallint(5) unsigned NOT NULL, 63 | `postal_code` varchar(10) DEFAULT NULL, 64 | `phone` varchar(20) NOT NULL, 65 | `location` geometry NOT NULL, 66 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 67 | PRIMARY KEY (`address_id`), 68 | KEY `idx_fk_city_id` (`city_id`), 69 | SPATIAL KEY `idx_location` (`location`), 70 | CONSTRAINT `fk_address_city` FOREIGN KEY (`city_id`) REFERENCES `city` (`city_id`) ON UPDATE CASCADE 71 | ) ENGINE=InnoDB AUTO_INCREMENT=606 DEFAULT CHARSET=utf8; 72 | /*!40101 SET character_set_client = @saved_cs_client */; 73 | 74 | -- 75 | -- Table structure for table `category` 76 | -- 77 | 78 | DROP TABLE IF EXISTS `category`; 79 | /*!40101 SET @saved_cs_client = @@character_set_client */; 80 | /*!40101 SET character_set_client = utf8 */; 81 | CREATE TABLE `category` ( 82 | `category_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 83 | `name` varchar(25) NOT NULL, 84 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 85 | PRIMARY KEY (`category_id`) 86 | ) ENGINE=InnoDB AUTO_INCREMENT=17 DEFAULT CHARSET=utf8; 87 | /*!40101 SET character_set_client = @saved_cs_client */; 88 | 89 | -- 90 | -- Table structure for table `city` 91 | -- 92 | 93 | DROP TABLE IF EXISTS `city`; 94 | /*!40101 SET @saved_cs_client = @@character_set_client */; 95 | /*!40101 SET character_set_client = utf8 */; 96 | CREATE TABLE `city` ( 97 | `city_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 98 | `city` varchar(50) NOT NULL, 99 | `country_id` smallint(5) unsigned NOT NULL, 100 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 101 | PRIMARY KEY (`city_id`), 102 | KEY `idx_fk_country_id` (`country_id`), 103 | CONSTRAINT `fk_city_country` FOREIGN KEY (`country_id`) REFERENCES `country` (`country_id`) ON UPDATE CASCADE 104 | ) ENGINE=InnoDB AUTO_INCREMENT=601 DEFAULT CHARSET=utf8; 105 | /*!40101 SET character_set_client = @saved_cs_client */; 106 | 107 | -- 108 | -- Table structure for table `country` 109 | -- 110 | 111 | DROP TABLE IF EXISTS `country`; 112 | /*!40101 SET @saved_cs_client = @@character_set_client */; 113 | /*!40101 SET character_set_client = utf8 */; 114 | CREATE TABLE `country` ( 115 | `country_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 116 | `country` varchar(50) NOT NULL, 117 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 118 | PRIMARY KEY (`country_id`) 119 | ) ENGINE=InnoDB AUTO_INCREMENT=110 DEFAULT CHARSET=utf8; 120 | /*!40101 SET character_set_client = @saved_cs_client */; 121 | 122 | -- 123 | -- Table structure for table `customer` 124 | -- 125 | 126 | DROP TABLE IF EXISTS `customer`; 127 | /*!40101 SET @saved_cs_client = @@character_set_client */; 128 | /*!40101 SET character_set_client = utf8 */; 129 | CREATE TABLE `customer` ( 130 | `customer_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 131 | `store_id` tinyint(3) unsigned NOT NULL, 132 | `first_name` varchar(45) NOT NULL, 133 | `last_name` varchar(45) NOT NULL, 134 | `email` varchar(50) DEFAULT NULL, 135 | `address_id` smallint(5) unsigned NOT NULL, 136 | `active` tinyint(1) NOT NULL DEFAULT '1', 137 | `create_date` datetime NOT NULL, 138 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 139 | PRIMARY KEY (`customer_id`), 140 | KEY `idx_fk_store_id` (`store_id`), 141 | KEY `idx_fk_address_id` (`address_id`), 142 | KEY `idx_last_name` (`last_name`), 143 | CONSTRAINT `fk_customer_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 144 | CONSTRAINT `fk_customer_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 145 | ) ENGINE=InnoDB AUTO_INCREMENT=600 DEFAULT CHARSET=utf8; 146 | /*!40101 SET character_set_client = @saved_cs_client */; 147 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 148 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 149 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 150 | /*!50003 SET character_set_client = utf8 */ ; 151 | /*!50003 SET character_set_results = utf8 */ ; 152 | /*!50003 SET collation_connection = utf8_general_ci */ ; 153 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 154 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 155 | DELIMITER ;; 156 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER customer_create_date BEFORE INSERT ON customer 157 | 158 | FOR EACH ROW SET NEW.create_date = NOW() */;; 159 | DELIMITER ; 160 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 161 | /*!50003 SET character_set_client = @saved_cs_client */ ; 162 | /*!50003 SET character_set_results = @saved_cs_results */ ; 163 | /*!50003 SET collation_connection = @saved_col_connection */ ; 164 | 165 | -- 166 | -- Temporary view structure for view `customer_list` 167 | -- 168 | 169 | DROP TABLE IF EXISTS `customer_list`; 170 | /*!50001 DROP VIEW IF EXISTS `customer_list`*/; 171 | SET @saved_cs_client = @@character_set_client; 172 | SET character_set_client = utf8; 173 | /*!50001 CREATE VIEW `customer_list` AS SELECT 174 | 1 AS `ID`, 175 | 1 AS `name`, 176 | 1 AS `address`, 177 | 1 AS `zip code`, 178 | 1 AS `phone`, 179 | 1 AS `city`, 180 | 1 AS `country`, 181 | 1 AS `notes`, 182 | 1 AS `SID`*/; 183 | SET character_set_client = @saved_cs_client; 184 | 185 | -- 186 | -- Table structure for table `film` 187 | -- 188 | 189 | DROP TABLE IF EXISTS `film`; 190 | /*!40101 SET @saved_cs_client = @@character_set_client */; 191 | /*!40101 SET character_set_client = utf8 */; 192 | CREATE TABLE `film` ( 193 | `film_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 194 | `title` varchar(255) NOT NULL, 195 | `description` text, 196 | `release_year` year(4) DEFAULT NULL, 197 | `language_id` tinyint(3) unsigned NOT NULL, 198 | `original_language_id` tinyint(3) unsigned DEFAULT NULL, 199 | `rental_duration` tinyint(3) unsigned NOT NULL DEFAULT '3', 200 | `rental_rate` decimal(4,2) NOT NULL DEFAULT '4.99', 201 | `length` smallint(5) unsigned DEFAULT NULL, 202 | `replacement_cost` decimal(5,2) NOT NULL DEFAULT '19.99', 203 | `rating` enum('G','PG','PG-13','R','NC-17') DEFAULT 'G', 204 | `special_features` set('Trailers','Commentaries','Deleted Scenes','Behind the Scenes') DEFAULT NULL, 205 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 206 | PRIMARY KEY (`film_id`), 207 | KEY `idx_title` (`title`), 208 | KEY `idx_fk_language_id` (`language_id`), 209 | KEY `idx_fk_original_language_id` (`original_language_id`), 210 | CONSTRAINT `fk_film_language` FOREIGN KEY (`language_id`) REFERENCES `language` (`language_id`) ON UPDATE CASCADE, 211 | CONSTRAINT `fk_film_language_original` FOREIGN KEY (`original_language_id`) REFERENCES `language` (`language_id`) ON UPDATE CASCADE 212 | ) ENGINE=InnoDB AUTO_INCREMENT=1001 DEFAULT CHARSET=utf8; 213 | /*!40101 SET character_set_client = @saved_cs_client */; 214 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 215 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 216 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 217 | /*!50003 SET character_set_client = utf8 */ ; 218 | /*!50003 SET character_set_results = utf8 */ ; 219 | /*!50003 SET collation_connection = utf8_general_ci */ ; 220 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 221 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 222 | DELIMITER ;; 223 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `ins_film` AFTER INSERT ON `film` FOR EACH ROW BEGIN 224 | INSERT INTO film_text (film_id, title, description) 225 | VALUES (new.film_id, new.title, new.description); 226 | END */;; 227 | DELIMITER ; 228 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 229 | /*!50003 SET character_set_client = @saved_cs_client */ ; 230 | /*!50003 SET character_set_results = @saved_cs_results */ ; 231 | /*!50003 SET collation_connection = @saved_col_connection */ ; 232 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 233 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 234 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 235 | /*!50003 SET character_set_client = utf8 */ ; 236 | /*!50003 SET character_set_results = utf8 */ ; 237 | /*!50003 SET collation_connection = utf8_general_ci */ ; 238 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 239 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 240 | DELIMITER ;; 241 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `upd_film` AFTER UPDATE ON `film` FOR EACH ROW BEGIN 242 | IF (old.title != new.title) OR (old.description != new.description) OR (old.film_id != new.film_id) 243 | THEN 244 | UPDATE film_text 245 | SET title=new.title, 246 | description=new.description, 247 | film_id=new.film_id 248 | WHERE film_id=old.film_id; 249 | END IF; 250 | END */;; 251 | DELIMITER ; 252 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 253 | /*!50003 SET character_set_client = @saved_cs_client */ ; 254 | /*!50003 SET character_set_results = @saved_cs_results */ ; 255 | /*!50003 SET collation_connection = @saved_col_connection */ ; 256 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 257 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 258 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 259 | /*!50003 SET character_set_client = utf8 */ ; 260 | /*!50003 SET character_set_results = utf8 */ ; 261 | /*!50003 SET collation_connection = utf8_general_ci */ ; 262 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 263 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 264 | DELIMITER ;; 265 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `del_film` AFTER DELETE ON `film` FOR EACH ROW BEGIN 266 | DELETE FROM film_text WHERE film_id = old.film_id; 267 | END */;; 268 | DELIMITER ; 269 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 270 | /*!50003 SET character_set_client = @saved_cs_client */ ; 271 | /*!50003 SET character_set_results = @saved_cs_results */ ; 272 | /*!50003 SET collation_connection = @saved_col_connection */ ; 273 | 274 | -- 275 | -- Table structure for table `film_actor` 276 | -- 277 | 278 | DROP TABLE IF EXISTS `film_actor`; 279 | /*!40101 SET @saved_cs_client = @@character_set_client */; 280 | /*!40101 SET character_set_client = utf8 */; 281 | CREATE TABLE `film_actor` ( 282 | `actor_id` smallint(5) unsigned NOT NULL, 283 | `film_id` smallint(5) unsigned NOT NULL, 284 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 285 | PRIMARY KEY (`actor_id`,`film_id`), 286 | KEY `idx_fk_film_id` (`film_id`), 287 | CONSTRAINT `fk_film_actor_actor` FOREIGN KEY (`actor_id`) REFERENCES `actor` (`actor_id`) ON UPDATE CASCADE, 288 | CONSTRAINT `fk_film_actor_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE 289 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 290 | /*!40101 SET character_set_client = @saved_cs_client */; 291 | 292 | -- 293 | -- Table structure for table `film_category` 294 | -- 295 | 296 | DROP TABLE IF EXISTS `film_category`; 297 | /*!40101 SET @saved_cs_client = @@character_set_client */; 298 | /*!40101 SET character_set_client = utf8 */; 299 | CREATE TABLE `film_category` ( 300 | `film_id` smallint(5) unsigned NOT NULL, 301 | `category_id` tinyint(3) unsigned NOT NULL, 302 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 303 | PRIMARY KEY (`film_id`,`category_id`), 304 | KEY `fk_film_category_category` (`category_id`), 305 | CONSTRAINT `fk_film_category_category` FOREIGN KEY (`category_id`) REFERENCES `category` (`category_id`) ON UPDATE CASCADE, 306 | CONSTRAINT `fk_film_category_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE 307 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 308 | /*!40101 SET character_set_client = @saved_cs_client */; 309 | 310 | -- 311 | -- Temporary view structure for view `film_list` 312 | -- 313 | 314 | DROP TABLE IF EXISTS `film_list`; 315 | /*!50001 DROP VIEW IF EXISTS `film_list`*/; 316 | SET @saved_cs_client = @@character_set_client; 317 | SET character_set_client = utf8; 318 | /*!50001 CREATE VIEW `film_list` AS SELECT 319 | 1 AS `FID`, 320 | 1 AS `title`, 321 | 1 AS `description`, 322 | 1 AS `category`, 323 | 1 AS `price`, 324 | 1 AS `length`, 325 | 1 AS `rating`, 326 | 1 AS `actors`*/; 327 | SET character_set_client = @saved_cs_client; 328 | 329 | -- 330 | -- Table structure for table `film_text` 331 | -- 332 | 333 | DROP TABLE IF EXISTS `film_text`; 334 | /*!40101 SET @saved_cs_client = @@character_set_client */; 335 | /*!40101 SET character_set_client = utf8 */; 336 | CREATE TABLE `film_text` ( 337 | `film_id` smallint(6) NOT NULL, 338 | `title` varchar(255) NOT NULL, 339 | `description` text, 340 | PRIMARY KEY (`film_id`), 341 | FULLTEXT KEY `idx_title_description` (`title`,`description`) 342 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 343 | /*!40101 SET character_set_client = @saved_cs_client */; 344 | 345 | -- 346 | -- Table structure for table `inventory` 347 | -- 348 | 349 | DROP TABLE IF EXISTS `inventory`; 350 | /*!40101 SET @saved_cs_client = @@character_set_client */; 351 | /*!40101 SET character_set_client = utf8 */; 352 | CREATE TABLE `inventory` ( 353 | `inventory_id` mediumint(8) unsigned NOT NULL AUTO_INCREMENT, 354 | `film_id` smallint(5) unsigned NOT NULL, 355 | `store_id` tinyint(3) unsigned NOT NULL, 356 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 357 | PRIMARY KEY (`inventory_id`), 358 | KEY `idx_fk_film_id` (`film_id`), 359 | KEY `idx_store_id_film_id` (`store_id`,`film_id`), 360 | CONSTRAINT `fk_inventory_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE, 361 | CONSTRAINT `fk_inventory_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 362 | ) ENGINE=InnoDB AUTO_INCREMENT=4582 DEFAULT CHARSET=utf8; 363 | /*!40101 SET character_set_client = @saved_cs_client */; 364 | 365 | -- 366 | -- Table structure for table `language` 367 | -- 368 | 369 | DROP TABLE IF EXISTS `language`; 370 | /*!40101 SET @saved_cs_client = @@character_set_client */; 371 | /*!40101 SET character_set_client = utf8 */; 372 | CREATE TABLE `language` ( 373 | `language_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 374 | `name` char(20) NOT NULL, 375 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 376 | PRIMARY KEY (`language_id`) 377 | ) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8; 378 | /*!40101 SET character_set_client = @saved_cs_client */; 379 | 380 | -- 381 | -- Temporary view structure for view `nicer_but_slower_film_list` 382 | -- 383 | 384 | DROP TABLE IF EXISTS `nicer_but_slower_film_list`; 385 | /*!50001 DROP VIEW IF EXISTS `nicer_but_slower_film_list`*/; 386 | SET @saved_cs_client = @@character_set_client; 387 | SET character_set_client = utf8; 388 | /*!50001 CREATE VIEW `nicer_but_slower_film_list` AS SELECT 389 | 1 AS `FID`, 390 | 1 AS `title`, 391 | 1 AS `description`, 392 | 1 AS `category`, 393 | 1 AS `price`, 394 | 1 AS `length`, 395 | 1 AS `rating`, 396 | 1 AS `actors`*/; 397 | SET character_set_client = @saved_cs_client; 398 | 399 | -- 400 | -- Table structure for table `payment` 401 | -- 402 | 403 | DROP TABLE IF EXISTS `payment`; 404 | /*!40101 SET @saved_cs_client = @@character_set_client */; 405 | /*!40101 SET character_set_client = utf8 */; 406 | CREATE TABLE `payment` ( 407 | `payment_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 408 | `customer_id` smallint(5) unsigned NOT NULL, 409 | `staff_id` tinyint(3) unsigned NOT NULL, 410 | `rental_id` int(11) DEFAULT NULL, 411 | `amount` decimal(5,2) NOT NULL, 412 | `payment_date` datetime NOT NULL, 413 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 414 | PRIMARY KEY (`payment_id`), 415 | KEY `idx_fk_staff_id` (`staff_id`), 416 | KEY `idx_fk_customer_id` (`customer_id`), 417 | KEY `fk_payment_rental` (`rental_id`), 418 | CONSTRAINT `fk_payment_customer` FOREIGN KEY (`customer_id`) REFERENCES `customer` (`customer_id`) ON UPDATE CASCADE, 419 | CONSTRAINT `fk_payment_rental` FOREIGN KEY (`rental_id`) REFERENCES `rental` (`rental_id`) ON DELETE SET NULL ON UPDATE CASCADE, 420 | CONSTRAINT `fk_payment_staff` FOREIGN KEY (`staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 421 | ) ENGINE=InnoDB AUTO_INCREMENT=16050 DEFAULT CHARSET=utf8; 422 | /*!40101 SET character_set_client = @saved_cs_client */; 423 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 424 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 425 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 426 | /*!50003 SET character_set_client = utf8 */ ; 427 | /*!50003 SET character_set_results = utf8 */ ; 428 | /*!50003 SET collation_connection = utf8_general_ci */ ; 429 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 430 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 431 | DELIMITER ;; 432 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER payment_date BEFORE INSERT ON payment 433 | 434 | FOR EACH ROW SET NEW.payment_date = NOW() */;; 435 | DELIMITER ; 436 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 437 | /*!50003 SET character_set_client = @saved_cs_client */ ; 438 | /*!50003 SET character_set_results = @saved_cs_results */ ; 439 | /*!50003 SET collation_connection = @saved_col_connection */ ; 440 | 441 | -- 442 | -- Table structure for table `rental` 443 | -- 444 | 445 | DROP TABLE IF EXISTS `rental`; 446 | /*!40101 SET @saved_cs_client = @@character_set_client */; 447 | /*!40101 SET character_set_client = utf8 */; 448 | CREATE TABLE `rental` ( 449 | `rental_id` int(11) NOT NULL AUTO_INCREMENT, 450 | `rental_date` datetime NOT NULL, 451 | `inventory_id` mediumint(8) unsigned NOT NULL, 452 | `customer_id` smallint(5) unsigned NOT NULL, 453 | `return_date` datetime DEFAULT NULL, 454 | `staff_id` tinyint(3) unsigned NOT NULL, 455 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 456 | PRIMARY KEY (`rental_id`), 457 | UNIQUE KEY `rental_date` (`rental_date`,`inventory_id`,`customer_id`), 458 | KEY `idx_fk_inventory_id` (`inventory_id`), 459 | KEY `idx_fk_customer_id` (`customer_id`), 460 | KEY `idx_fk_staff_id` (`staff_id`), 461 | CONSTRAINT `fk_rental_customer` FOREIGN KEY (`customer_id`) REFERENCES `customer` (`customer_id`) ON UPDATE CASCADE, 462 | CONSTRAINT `fk_rental_inventory` FOREIGN KEY (`inventory_id`) REFERENCES `inventory` (`inventory_id`) ON UPDATE CASCADE, 463 | CONSTRAINT `fk_rental_staff` FOREIGN KEY (`staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 464 | ) ENGINE=InnoDB AUTO_INCREMENT=16050 DEFAULT CHARSET=utf8; 465 | /*!40101 SET character_set_client = @saved_cs_client */; 466 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 467 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 468 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 469 | /*!50003 SET character_set_client = utf8 */ ; 470 | /*!50003 SET character_set_results = utf8 */ ; 471 | /*!50003 SET collation_connection = utf8_general_ci */ ; 472 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 473 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 474 | DELIMITER ;; 475 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER rental_date BEFORE INSERT ON rental 476 | 477 | FOR EACH ROW SET NEW.rental_date = NOW() */;; 478 | DELIMITER ; 479 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 480 | /*!50003 SET character_set_client = @saved_cs_client */ ; 481 | /*!50003 SET character_set_results = @saved_cs_results */ ; 482 | /*!50003 SET collation_connection = @saved_col_connection */ ; 483 | 484 | -- 485 | -- Temporary view structure for view `sales_by_film_category` 486 | -- 487 | 488 | DROP TABLE IF EXISTS `sales_by_film_category`; 489 | /*!50001 DROP VIEW IF EXISTS `sales_by_film_category`*/; 490 | SET @saved_cs_client = @@character_set_client; 491 | SET character_set_client = utf8; 492 | /*!50001 CREATE VIEW `sales_by_film_category` AS SELECT 493 | 1 AS `category`, 494 | 1 AS `total_sales`*/; 495 | SET character_set_client = @saved_cs_client; 496 | 497 | -- 498 | -- Temporary view structure for view `sales_by_store` 499 | -- 500 | 501 | DROP TABLE IF EXISTS `sales_by_store`; 502 | /*!50001 DROP VIEW IF EXISTS `sales_by_store`*/; 503 | SET @saved_cs_client = @@character_set_client; 504 | SET character_set_client = utf8; 505 | /*!50001 CREATE VIEW `sales_by_store` AS SELECT 506 | 1 AS `store`, 507 | 1 AS `manager`, 508 | 1 AS `total_sales`*/; 509 | SET character_set_client = @saved_cs_client; 510 | 511 | -- 512 | -- Table structure for table `staff` 513 | -- 514 | 515 | DROP TABLE IF EXISTS `staff`; 516 | /*!40101 SET @saved_cs_client = @@character_set_client */; 517 | /*!40101 SET character_set_client = utf8 */; 518 | CREATE TABLE `staff` ( 519 | `staff_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 520 | `first_name` varchar(45) NOT NULL, 521 | `last_name` varchar(45) NOT NULL, 522 | `address_id` smallint(5) unsigned NOT NULL, 523 | `picture` blob, 524 | `email` varchar(50) DEFAULT NULL, 525 | `store_id` tinyint(3) unsigned NOT NULL, 526 | `active` tinyint(1) NOT NULL DEFAULT '1', 527 | `username` varchar(16) NOT NULL, 528 | `password` varchar(40) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL, 529 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 530 | PRIMARY KEY (`staff_id`), 531 | KEY `idx_fk_store_id` (`store_id`), 532 | KEY `idx_fk_address_id` (`address_id`), 533 | CONSTRAINT `fk_staff_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 534 | CONSTRAINT `fk_staff_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 535 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 536 | /*!40101 SET character_set_client = @saved_cs_client */; 537 | 538 | -- 539 | -- Temporary view structure for view `staff_list` 540 | -- 541 | 542 | DROP TABLE IF EXISTS `staff_list`; 543 | /*!50001 DROP VIEW IF EXISTS `staff_list`*/; 544 | SET @saved_cs_client = @@character_set_client; 545 | SET character_set_client = utf8; 546 | /*!50001 CREATE VIEW `staff_list` AS SELECT 547 | 1 AS `ID`, 548 | 1 AS `name`, 549 | 1 AS `address`, 550 | 1 AS `zip code`, 551 | 1 AS `phone`, 552 | 1 AS `city`, 553 | 1 AS `country`, 554 | 1 AS `SID`*/; 555 | SET character_set_client = @saved_cs_client; 556 | 557 | -- 558 | -- Table structure for table `store` 559 | -- 560 | 561 | DROP TABLE IF EXISTS `store`; 562 | /*!40101 SET @saved_cs_client = @@character_set_client */; 563 | /*!40101 SET character_set_client = utf8 */; 564 | CREATE TABLE `store` ( 565 | `store_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 566 | `manager_staff_id` tinyint(3) unsigned NOT NULL, 567 | `address_id` smallint(5) unsigned NOT NULL, 568 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 569 | PRIMARY KEY (`store_id`), 570 | UNIQUE KEY `idx_unique_manager` (`manager_staff_id`), 571 | KEY `idx_fk_address_id` (`address_id`), 572 | CONSTRAINT `fk_store_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 573 | CONSTRAINT `fk_store_staff` FOREIGN KEY (`manager_staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 574 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 575 | /*!40101 SET character_set_client = @saved_cs_client */; 576 | 577 | -- 578 | -- Table structure for table `test` 579 | -- 580 | 581 | DROP TABLE IF EXISTS `test`; 582 | /*!40101 SET @saved_cs_client = @@character_set_client */; 583 | /*!40101 SET character_set_client = utf8 */; 584 | CREATE TABLE `test` ( 585 | `test1` int(10) DEFAULT NULL 586 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT='table''s comment'; 587 | /*!40101 SET character_set_client = @saved_cs_client */; 588 | 589 | -- 590 | -- Table structure for table `test1` 591 | -- 592 | 593 | DROP TABLE IF EXISTS `test1`; 594 | /*!40101 SET @saved_cs_client = @@character_set_client */; 595 | /*!40101 SET character_set_client = utf8 */; 596 | CREATE TABLE `test1` ( 597 | `id` int(11) NOT NULL AUTO_INCREMENT, 598 | `name` varchar(51) DEFAULT '''test''', 599 | PRIMARY KEY (`id`) 600 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 601 | /*!40101 SET character_set_client = @saved_cs_client */; 602 | 603 | -- 604 | -- Table structure for table `test2` 605 | -- 606 | 607 | DROP TABLE IF EXISTS `test2`; 608 | /*!40101 SET @saved_cs_client = @@character_set_client */; 609 | /*!40101 SET character_set_client = utf8 */; 610 | CREATE TABLE `test2` ( 611 | `id` int(11) NOT NULL AUTO_INCREMENT, 612 | `fk` int(10) NOT NULL, 613 | `val` decimal(10,2) NOT NULL, 614 | `texto` varchar(60) DEFAULT NULL, 615 | `datade` timestamp NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, 616 | PRIMARY KEY (`id`), 617 | KEY `FK__test1` (`fk`), 618 | CONSTRAINT `FK__test1` FOREIGN KEY (`fk`) REFERENCES `test1` (`id`) 619 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 620 | /*!40101 SET character_set_client = @saved_cs_client */; 621 | 622 | -- 623 | -- Final view structure for view `actor_info` 624 | -- 625 | 626 | /*!50001 DROP VIEW IF EXISTS `actor_info`*/; 627 | /*!50001 SET @saved_cs_client = @@character_set_client */; 628 | /*!50001 SET @saved_cs_results = @@character_set_results */; 629 | /*!50001 SET @saved_col_connection = @@collation_connection */; 630 | /*!50001 SET character_set_client = utf8 */; 631 | /*!50001 SET character_set_results = utf8 */; 632 | /*!50001 SET collation_connection = utf8_general_ci */; 633 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 634 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY INVOKER */ 635 | /*!50001 VIEW `actor_info` AS select `a`.`actor_id` AS `actor_id`,`a`.`first_name` AS `first_name`,`a`.`last_name` AS `last_name`,group_concat(distinct concat(`c`.`name`,': ',(select group_concat(`f`.`title` order by `f`.`title` ASC separator ', ') from ((`film` `f` join `film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `film_actor` `fa` on((`f`.`film_id` = `fa`.`film_id`))) where ((`fc`.`category_id` = `c`.`category_id`) and (`fa`.`actor_id` = `a`.`actor_id`)))) order by `c`.`name` ASC separator '; ') AS `film_info` from (((`actor` `a` left join `film_actor` `fa` on((`a`.`actor_id` = `fa`.`actor_id`))) left join `film_category` `fc` on((`fa`.`film_id` = `fc`.`film_id`))) left join `category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `a`.`actor_id`,`a`.`first_name`,`a`.`last_name` */; 636 | /*!50001 SET character_set_client = @saved_cs_client */; 637 | /*!50001 SET character_set_results = @saved_cs_results */; 638 | /*!50001 SET collation_connection = @saved_col_connection */; 639 | 640 | -- 641 | -- Final view structure for view `customer_list` 642 | -- 643 | 644 | /*!50001 DROP VIEW IF EXISTS `customer_list`*/; 645 | /*!50001 SET @saved_cs_client = @@character_set_client */; 646 | /*!50001 SET @saved_cs_results = @@character_set_results */; 647 | /*!50001 SET @saved_col_connection = @@collation_connection */; 648 | /*!50001 SET character_set_client = utf8 */; 649 | /*!50001 SET character_set_results = utf8 */; 650 | /*!50001 SET collation_connection = utf8_general_ci */; 651 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 652 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 653 | /*!50001 VIEW `customer_list` AS select `cu`.`customer_id` AS `ID`,concat(`cu`.`first_name`,_utf8' ',`cu`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`city`.`city` AS `city`,`country`.`country` AS `country`,if(`cu`.`active`,_utf8'active',_utf8'') AS `notes`,`cu`.`store_id` AS `SID` from (((`customer` `cu` join `address` `a` on((`cu`.`address_id` = `a`.`address_id`))) join `city` on((`a`.`city_id` = `city`.`city_id`))) join `country` on((`city`.`country_id` = `country`.`country_id`))) */; 654 | /*!50001 SET character_set_client = @saved_cs_client */; 655 | /*!50001 SET character_set_results = @saved_cs_results */; 656 | /*!50001 SET collation_connection = @saved_col_connection */; 657 | 658 | -- 659 | -- Final view structure for view `film_list` 660 | -- 661 | 662 | /*!50001 DROP VIEW IF EXISTS `film_list`*/; 663 | /*!50001 SET @saved_cs_client = @@character_set_client */; 664 | /*!50001 SET @saved_cs_results = @@character_set_results */; 665 | /*!50001 SET @saved_col_connection = @@collation_connection */; 666 | /*!50001 SET character_set_client = utf8 */; 667 | /*!50001 SET character_set_results = utf8 */; 668 | /*!50001 SET collation_connection = utf8_general_ci */; 669 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 670 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 671 | /*!50001 VIEW `film_list` AS select `film`.`film_id` AS `FID`,`film`.`title` AS `title`,`film`.`description` AS `description`,`category`.`name` AS `category`,`film`.`rental_rate` AS `price`,`film`.`length` AS `length`,`film`.`rating` AS `rating`,group_concat(concat(`actor`.`first_name`,_utf8' ',`actor`.`last_name`) separator ', ') AS `actors` from ((((`category` left join `film_category` on((`category`.`category_id` = `film_category`.`category_id`))) left join `film` on((`film_category`.`film_id` = `film`.`film_id`))) join `film_actor` on((`film`.`film_id` = `film_actor`.`film_id`))) join `actor` on((`film_actor`.`actor_id` = `actor`.`actor_id`))) group by `film`.`film_id`,`category`.`name` */; 672 | /*!50001 SET character_set_client = @saved_cs_client */; 673 | /*!50001 SET character_set_results = @saved_cs_results */; 674 | /*!50001 SET collation_connection = @saved_col_connection */; 675 | 676 | -- 677 | -- Final view structure for view `nicer_but_slower_film_list` 678 | -- 679 | 680 | /*!50001 DROP VIEW IF EXISTS `nicer_but_slower_film_list`*/; 681 | /*!50001 SET @saved_cs_client = @@character_set_client */; 682 | /*!50001 SET @saved_cs_results = @@character_set_results */; 683 | /*!50001 SET @saved_col_connection = @@collation_connection */; 684 | /*!50001 SET character_set_client = utf8 */; 685 | /*!50001 SET character_set_results = utf8 */; 686 | /*!50001 SET collation_connection = utf8_general_ci */; 687 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 688 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 689 | /*!50001 VIEW `nicer_but_slower_film_list` AS select `film`.`film_id` AS `FID`,`film`.`title` AS `title`,`film`.`description` AS `description`,`category`.`name` AS `category`,`film`.`rental_rate` AS `price`,`film`.`length` AS `length`,`film`.`rating` AS `rating`,group_concat(concat(concat(upper(substr(`actor`.`first_name`,1,1)),lower(substr(`actor`.`first_name`,2,length(`actor`.`first_name`))),_utf8' ',concat(upper(substr(`actor`.`last_name`,1,1)),lower(substr(`actor`.`last_name`,2,length(`actor`.`last_name`)))))) separator ', ') AS `actors` from ((((`category` left join `film_category` on((`category`.`category_id` = `film_category`.`category_id`))) left join `film` on((`film_category`.`film_id` = `film`.`film_id`))) join `film_actor` on((`film`.`film_id` = `film_actor`.`film_id`))) join `actor` on((`film_actor`.`actor_id` = `actor`.`actor_id`))) group by `film`.`film_id`,`category`.`name` */; 690 | /*!50001 SET character_set_client = @saved_cs_client */; 691 | /*!50001 SET character_set_results = @saved_cs_results */; 692 | /*!50001 SET collation_connection = @saved_col_connection */; 693 | 694 | -- 695 | -- Final view structure for view `sales_by_film_category` 696 | -- 697 | 698 | /*!50001 DROP VIEW IF EXISTS `sales_by_film_category`*/; 699 | /*!50001 SET @saved_cs_client = @@character_set_client */; 700 | /*!50001 SET @saved_cs_results = @@character_set_results */; 701 | /*!50001 SET @saved_col_connection = @@collation_connection */; 702 | /*!50001 SET character_set_client = utf8 */; 703 | /*!50001 SET character_set_results = utf8 */; 704 | /*!50001 SET collation_connection = utf8_general_ci */; 705 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 706 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 707 | /*!50001 VIEW `sales_by_film_category` AS select `c`.`name` AS `category`,sum(`p`.`amount`) AS `total_sales` from (((((`payment` `p` join `rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `film` `f` on((`i`.`film_id` = `f`.`film_id`))) join `film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `c`.`name` order by `total_sales` desc */; 708 | /*!50001 SET character_set_client = @saved_cs_client */; 709 | /*!50001 SET character_set_results = @saved_cs_results */; 710 | /*!50001 SET collation_connection = @saved_col_connection */; 711 | 712 | -- 713 | -- Final view structure for view `sales_by_store` 714 | -- 715 | 716 | /*!50001 DROP VIEW IF EXISTS `sales_by_store`*/; 717 | /*!50001 SET @saved_cs_client = @@character_set_client */; 718 | /*!50001 SET @saved_cs_results = @@character_set_results */; 719 | /*!50001 SET @saved_col_connection = @@collation_connection */; 720 | /*!50001 SET character_set_client = utf8 */; 721 | /*!50001 SET character_set_results = utf8 */; 722 | /*!50001 SET collation_connection = utf8_general_ci */; 723 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 724 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 725 | /*!50001 VIEW `sales_by_store` AS select concat(`c`.`city`,_utf8',',`cy`.`country`) AS `store`,concat(`m`.`first_name`,_utf8' ',`m`.`last_name`) AS `manager`,sum(`p`.`amount`) AS `total_sales` from (((((((`payment` `p` join `rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `store` `s` on((`i`.`store_id` = `s`.`store_id`))) join `address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `city` `c` on((`a`.`city_id` = `c`.`city_id`))) join `country` `cy` on((`c`.`country_id` = `cy`.`country_id`))) join `staff` `m` on((`s`.`manager_staff_id` = `m`.`staff_id`))) group by `s`.`store_id` order by `cy`.`country`,`c`.`city` */; 726 | /*!50001 SET character_set_client = @saved_cs_client */; 727 | /*!50001 SET character_set_results = @saved_cs_results */; 728 | /*!50001 SET collation_connection = @saved_col_connection */; 729 | 730 | -- 731 | -- Final view structure for view `staff_list` 732 | -- 733 | 734 | /*!50001 DROP VIEW IF EXISTS `staff_list`*/; 735 | /*!50001 SET @saved_cs_client = @@character_set_client */; 736 | /*!50001 SET @saved_cs_results = @@character_set_results */; 737 | /*!50001 SET @saved_col_connection = @@collation_connection */; 738 | /*!50001 SET character_set_client = utf8 */; 739 | /*!50001 SET character_set_results = utf8 */; 740 | /*!50001 SET collation_connection = utf8_general_ci */; 741 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 742 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 743 | /*!50001 VIEW `staff_list` AS select `s`.`staff_id` AS `ID`,concat(`s`.`first_name`,_utf8' ',`s`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`city`.`city` AS `city`,`country`.`country` AS `country`,`s`.`store_id` AS `SID` from (((`staff` `s` join `address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `city` on((`a`.`city_id` = `city`.`city_id`))) join `country` on((`city`.`country_id` = `country`.`country_id`))) */; 744 | /*!50001 SET character_set_client = @saved_cs_client */; 745 | /*!50001 SET character_set_results = @saved_cs_results */; 746 | /*!50001 SET collation_connection = @saved_col_connection */; 747 | /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; 748 | 749 | /*!40101 SET SQL_MODE=@OLD_SQL_MODE */; 750 | /*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */; 751 | /*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */; 752 | /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; 753 | /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; 754 | /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; 755 | /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; 756 | 757 | -- Dump completed on 2016-04-08 9:05:53 758 | -------------------------------------------------------------------------------- /tests/fixtures/sakila_new.sql: -------------------------------------------------------------------------------- 1 | -- MySQL dump 10.13 Distrib 5.7.10, for Win64 (x86_64) 2 | -- 3 | -- Host: localhost Database: sakila 4 | -- ------------------------------------------------------ 5 | -- Server version 5.7.10-log 6 | 7 | /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; 8 | /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; 9 | /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; 10 | /*!40101 SET NAMES utf8 */; 11 | /*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */; 12 | /*!40103 SET TIME_ZONE='+00:00' */; 13 | /*!40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */; 14 | /*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */; 15 | /*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */; 16 | /*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */; 17 | 18 | -- 19 | -- Table structure for table `actor` 20 | -- 21 | 22 | DROP TABLE IF EXISTS `actor`; 23 | /*!40101 SET @saved_cs_client = @@character_set_client */; 24 | /*!40101 SET character_set_client = utf8 */; 25 | CREATE TABLE `actor` ( 26 | `actor_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 27 | `first_name` varchar(45) NOT NULL, 28 | `last_name` varchar(45) NOT NULL, 29 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 30 | PRIMARY KEY (`actor_id`), 31 | KEY `idx_actor_last_name` (`last_name`) 32 | ) ENGINE=InnoDB AUTO_INCREMENT=201 DEFAULT CHARSET=utf8; 33 | /*!40101 SET character_set_client = @saved_cs_client */; 34 | 35 | -- 36 | -- Temporary view structure for view `actor_info` 37 | -- 38 | 39 | DROP TABLE IF EXISTS `actor_info`; 40 | /*!50001 DROP VIEW IF EXISTS `actor_info`*/; 41 | SET @saved_cs_client = @@character_set_client; 42 | SET character_set_client = utf8; 43 | /*!50001 CREATE VIEW `actor_info` AS SELECT 44 | 1 AS `actor_id`, 45 | 1 AS `first_name`, 46 | 1 AS `last_name`, 47 | 1 AS `film_info`*/; 48 | SET character_set_client = @saved_cs_client; 49 | 50 | -- 51 | -- Table structure for table `address` 52 | -- 53 | 54 | DROP TABLE IF EXISTS `address`; 55 | /*!40101 SET @saved_cs_client = @@character_set_client */; 56 | /*!40101 SET character_set_client = utf8 */; 57 | CREATE TABLE `address` ( 58 | `address_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 59 | `address` varchar(50) NOT NULL, 60 | `address2` varchar(50) DEFAULT NULL, 61 | `district` varchar(20) NOT NULL, 62 | `city_id` smallint(5) unsigned NOT NULL, 63 | `postal_code` varchar(10) DEFAULT NULL, 64 | `phone` varchar(20) NOT NULL, 65 | `location` geometry NOT NULL, 66 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 67 | PRIMARY KEY (`address_id`), 68 | KEY `idx_fk_city_id` (`city_id`), 69 | SPATIAL KEY `idx_location` (`location`), 70 | CONSTRAINT `fk_address_city` FOREIGN KEY (`city_id`) REFERENCES `city` (`city_id`) ON UPDATE CASCADE 71 | ) ENGINE=InnoDB AUTO_INCREMENT=606 DEFAULT CHARSET=utf8; 72 | /*!40101 SET character_set_client = @saved_cs_client */; 73 | 74 | -- 75 | -- Table structure for table `category` 76 | -- 77 | 78 | DROP TABLE IF EXISTS `category`; 79 | /*!40101 SET @saved_cs_client = @@character_set_client */; 80 | /*!40101 SET character_set_client = utf8 */; 81 | CREATE TABLE `category` ( 82 | `category_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 83 | `name` varchar(25) NOT NULL, 84 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 85 | PRIMARY KEY (`category_id`) 86 | ) ENGINE=InnoDB AUTO_INCREMENT=17 DEFAULT CHARSET=utf8; 87 | /*!40101 SET character_set_client = @saved_cs_client */; 88 | 89 | -- 90 | -- Table structure for table `city` 91 | -- 92 | 93 | DROP TABLE IF EXISTS `city`; 94 | /*!40101 SET @saved_cs_client = @@character_set_client */; 95 | /*!40101 SET character_set_client = utf8 */; 96 | CREATE TABLE `city` ( 97 | `city_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 98 | `city` varchar(50) NOT NULL, 99 | `country_id` smallint(5) unsigned NOT NULL, 100 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 101 | PRIMARY KEY (`city_id`), 102 | KEY `idx_fk_country_id` (`country_id`), 103 | CONSTRAINT `fk_city_country` FOREIGN KEY (`country_id`) REFERENCES `country` (`country_id`) ON UPDATE CASCADE 104 | ) ENGINE=InnoDB AUTO_INCREMENT=601 DEFAULT CHARSET=utf8; 105 | /*!40101 SET character_set_client = @saved_cs_client */; 106 | 107 | -- 108 | -- Table structure for table `country` 109 | -- 110 | 111 | DROP TABLE IF EXISTS `country`; 112 | /*!40101 SET @saved_cs_client = @@character_set_client */; 113 | /*!40101 SET character_set_client = utf8 */; 114 | CREATE TABLE `country` ( 115 | `country_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 116 | `country` varchar(50) NOT NULL, 117 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 118 | PRIMARY KEY (`country_id`) 119 | ) ENGINE=InnoDB AUTO_INCREMENT=110 DEFAULT CHARSET=utf8; 120 | /*!40101 SET character_set_client = @saved_cs_client */; 121 | 122 | -- 123 | -- Table structure for table `customer` 124 | -- 125 | 126 | DROP TABLE IF EXISTS `customer`; 127 | /*!40101 SET @saved_cs_client = @@character_set_client */; 128 | /*!40101 SET character_set_client = utf8 */; 129 | CREATE TABLE `customer` ( 130 | `customer_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 131 | `store_id` tinyint(3) unsigned NOT NULL, 132 | `first_name` varchar(45) NOT NULL, 133 | `last_name` varchar(45) NOT NULL, 134 | `email` varchar(50) DEFAULT NULL, 135 | `address_id` smallint(5) unsigned NOT NULL, 136 | `active` tinyint(1) NOT NULL DEFAULT '1', 137 | `create_date` datetime NOT NULL, 138 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 139 | PRIMARY KEY (`customer_id`), 140 | KEY `idx_fk_store_id` (`store_id`), 141 | KEY `idx_fk_address_id` (`address_id`), 142 | KEY `idx_last_name` (`last_name`), 143 | CONSTRAINT `fk_customer_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 144 | CONSTRAINT `fk_customer_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 145 | ) ENGINE=InnoDB AUTO_INCREMENT=600 DEFAULT CHARSET=utf8; 146 | /*!40101 SET character_set_client = @saved_cs_client */; 147 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 148 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 149 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 150 | /*!50003 SET character_set_client = utf8 */ ; 151 | /*!50003 SET character_set_results = utf8 */ ; 152 | /*!50003 SET collation_connection = utf8_general_ci */ ; 153 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 154 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 155 | DELIMITER ;; 156 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER customer_create_date BEFORE INSERT ON customer 157 | 158 | FOR EACH ROW SET NEW.create_date = NOW() */;; 159 | DELIMITER ; 160 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 161 | /*!50003 SET character_set_client = @saved_cs_client */ ; 162 | /*!50003 SET character_set_results = @saved_cs_results */ ; 163 | /*!50003 SET collation_connection = @saved_col_connection */ ; 164 | 165 | -- 166 | -- Temporary view structure for view `customer_list` 167 | -- 168 | 169 | DROP TABLE IF EXISTS `customer_list`; 170 | /*!50001 DROP VIEW IF EXISTS `customer_list`*/; 171 | SET @saved_cs_client = @@character_set_client; 172 | SET character_set_client = utf8; 173 | /*!50001 CREATE VIEW `customer_list` AS SELECT 174 | 1 AS `ID`, 175 | 1 AS `name`, 176 | 1 AS `address`, 177 | 1 AS `zip code`, 178 | 1 AS `phone`, 179 | 1 AS `city`, 180 | 1 AS `country`, 181 | 1 AS `notes`, 182 | 1 AS `SID`*/; 183 | SET character_set_client = @saved_cs_client; 184 | 185 | -- 186 | -- Table structure for table `film` 187 | -- 188 | 189 | DROP TABLE IF EXISTS `film`; 190 | /*!40101 SET @saved_cs_client = @@character_set_client */; 191 | /*!40101 SET character_set_client = utf8 */; 192 | CREATE TABLE `film` ( 193 | `film_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 194 | `title` varchar(255) NOT NULL, 195 | `description` text, 196 | `release_year` year(4) DEFAULT NULL, 197 | `language_id` tinyint(3) unsigned NOT NULL, 198 | `original_language_id` tinyint(3) unsigned DEFAULT NULL, 199 | `rental_duration` tinyint(3) unsigned NOT NULL DEFAULT '3', 200 | `rental_rate` decimal(4,2) NOT NULL DEFAULT '4.99', 201 | `length` smallint(5) unsigned DEFAULT NULL, 202 | `replacement_cost` decimal(5,2) NOT NULL DEFAULT '19.99', 203 | `rating` enum('G','PG','PG-13','R','NC-17') DEFAULT 'G', 204 | `special_features` set('Trailers','Commentaries','Deleted Scenes','Behind the Scenes') DEFAULT NULL, 205 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 206 | PRIMARY KEY (`film_id`), 207 | KEY `idx_title` (`title`), 208 | KEY `idx_fk_language_id` (`language_id`), 209 | KEY `idx_fk_original_language_id` (`original_language_id`), 210 | CONSTRAINT `fk_film_language` FOREIGN KEY (`language_id`) REFERENCES `language` (`language_id`) ON UPDATE CASCADE, 211 | CONSTRAINT `fk_film_language_original` FOREIGN KEY (`original_language_id`) REFERENCES `language` (`language_id`) ON UPDATE CASCADE 212 | ) ENGINE=InnoDB AUTO_INCREMENT=1001 DEFAULT CHARSET=utf8; 213 | /*!40101 SET character_set_client = @saved_cs_client */; 214 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 215 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 216 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 217 | /*!50003 SET character_set_client = utf8 */ ; 218 | /*!50003 SET character_set_results = utf8 */ ; 219 | /*!50003 SET collation_connection = utf8_general_ci */ ; 220 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 221 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 222 | DELIMITER ;; 223 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `ins_film` AFTER INSERT ON `film` FOR EACH ROW BEGIN 224 | INSERT INTO film_text (film_id, title, description) 225 | VALUES (new.film_id, new.title, new.description); 226 | END */;; 227 | DELIMITER ; 228 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 229 | /*!50003 SET character_set_client = @saved_cs_client */ ; 230 | /*!50003 SET character_set_results = @saved_cs_results */ ; 231 | /*!50003 SET collation_connection = @saved_col_connection */ ; 232 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 233 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 234 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 235 | /*!50003 SET character_set_client = utf8 */ ; 236 | /*!50003 SET character_set_results = utf8 */ ; 237 | /*!50003 SET collation_connection = utf8_general_ci */ ; 238 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 239 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 240 | DELIMITER ;; 241 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `upd_film` AFTER UPDATE ON `film` FOR EACH ROW BEGIN 242 | IF (old.title != new.title) OR (old.description != new.description) OR (old.film_id != new.film_id) 243 | THEN 244 | UPDATE film_text 245 | SET title=new.title, 246 | description=new.description, 247 | film_id=new.film_id 248 | WHERE film_id=old.film_id; 249 | END IF; 250 | END */;; 251 | DELIMITER ; 252 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 253 | /*!50003 SET character_set_client = @saved_cs_client */ ; 254 | /*!50003 SET character_set_results = @saved_cs_results */ ; 255 | /*!50003 SET collation_connection = @saved_col_connection */ ; 256 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 257 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 258 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 259 | /*!50003 SET character_set_client = utf8 */ ; 260 | /*!50003 SET character_set_results = utf8 */ ; 261 | /*!50003 SET collation_connection = utf8_general_ci */ ; 262 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 263 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 264 | DELIMITER ;; 265 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER `del_film` AFTER DELETE ON `film` FOR EACH ROW BEGIN 266 | DELETE FROM film_text WHERE film_id = old.film_id; 267 | END */;; 268 | DELIMITER ; 269 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 270 | /*!50003 SET character_set_client = @saved_cs_client */ ; 271 | /*!50003 SET character_set_results = @saved_cs_results */ ; 272 | /*!50003 SET collation_connection = @saved_col_connection */ ; 273 | 274 | -- 275 | -- Table structure for table `film_actor` 276 | -- 277 | 278 | DROP TABLE IF EXISTS `film_actor`; 279 | /*!40101 SET @saved_cs_client = @@character_set_client */; 280 | /*!40101 SET character_set_client = utf8 */; 281 | CREATE TABLE `film_actor` ( 282 | `actor_id` smallint(5) unsigned NOT NULL, 283 | `film_id` smallint(5) unsigned NOT NULL, 284 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 285 | PRIMARY KEY (`actor_id`,`film_id`), 286 | KEY `idx_fk_film_id` (`film_id`), 287 | CONSTRAINT `fk_film_actor_actor` FOREIGN KEY (`actor_id`) REFERENCES `actor` (`actor_id`) ON UPDATE CASCADE, 288 | CONSTRAINT `fk_film_actor_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE 289 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 290 | /*!40101 SET character_set_client = @saved_cs_client */; 291 | 292 | -- 293 | -- Table structure for table `film_category` 294 | -- 295 | 296 | DROP TABLE IF EXISTS `film_category`; 297 | /*!40101 SET @saved_cs_client = @@character_set_client */; 298 | /*!40101 SET character_set_client = utf8 */; 299 | CREATE TABLE `film_category` ( 300 | `film_id` smallint(5) unsigned NOT NULL, 301 | `category_id` tinyint(3) unsigned NOT NULL, 302 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 303 | PRIMARY KEY (`film_id`,`category_id`), 304 | KEY `fk_film_category_category` (`category_id`), 305 | CONSTRAINT `fk_film_category_category` FOREIGN KEY (`category_id`) REFERENCES `category` (`category_id`) ON UPDATE CASCADE, 306 | CONSTRAINT `fk_film_category_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE 307 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 308 | /*!40101 SET character_set_client = @saved_cs_client */; 309 | 310 | -- 311 | -- Temporary view structure for view `film_list` 312 | -- 313 | 314 | DROP TABLE IF EXISTS `film_list`; 315 | /*!50001 DROP VIEW IF EXISTS `film_list`*/; 316 | SET @saved_cs_client = @@character_set_client; 317 | SET character_set_client = utf8; 318 | /*!50001 CREATE VIEW `film_list` AS SELECT 319 | 1 AS `FID`, 320 | 1 AS `title`, 321 | 1 AS `description`, 322 | 1 AS `category`, 323 | 1 AS `price`, 324 | 1 AS `length`, 325 | 1 AS `rating`, 326 | 1 AS `actors`*/; 327 | SET character_set_client = @saved_cs_client; 328 | 329 | -- 330 | -- Table structure for table `film_text` 331 | -- 332 | 333 | DROP TABLE IF EXISTS `film_text`; 334 | /*!40101 SET @saved_cs_client = @@character_set_client */; 335 | /*!40101 SET character_set_client = utf8 */; 336 | CREATE TABLE `film_text` ( 337 | `film_id` smallint(6) NOT NULL, 338 | `title` varchar(255) NOT NULL, 339 | `description` text, 340 | PRIMARY KEY (`film_id`), 341 | FULLTEXT KEY `idx_title_description` (`title`,`description`) 342 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8; 343 | /*!40101 SET character_set_client = @saved_cs_client */; 344 | 345 | -- 346 | -- Table structure for table `inventory` 347 | -- 348 | 349 | DROP TABLE IF EXISTS `inventory`; 350 | /*!40101 SET @saved_cs_client = @@character_set_client */; 351 | /*!40101 SET character_set_client = utf8 */; 352 | CREATE TABLE `inventory` ( 353 | `inventory_id` mediumint(8) unsigned NOT NULL AUTO_INCREMENT, 354 | `film_id` smallint(5) unsigned NOT NULL, 355 | `store_id` tinyint(3) unsigned NOT NULL, 356 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 357 | PRIMARY KEY (`inventory_id`), 358 | KEY `idx_fk_film_id` (`film_id`), 359 | KEY `idx_store_id_film_id` (`store_id`,`film_id`), 360 | CONSTRAINT `fk_inventory_film` FOREIGN KEY (`film_id`) REFERENCES `film` (`film_id`) ON UPDATE CASCADE, 361 | CONSTRAINT `fk_inventory_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 362 | ) ENGINE=InnoDB AUTO_INCREMENT=4582 DEFAULT CHARSET=utf8; 363 | /*!40101 SET character_set_client = @saved_cs_client */; 364 | 365 | -- 366 | -- Table structure for table `language` 367 | -- 368 | 369 | DROP TABLE IF EXISTS `language`; 370 | /*!40101 SET @saved_cs_client = @@character_set_client */; 371 | /*!40101 SET character_set_client = utf8 */; 372 | CREATE TABLE `language` ( 373 | `language_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 374 | `name` char(20) NOT NULL, 375 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 376 | PRIMARY KEY (`language_id`) 377 | ) ENGINE=InnoDB AUTO_INCREMENT=7 DEFAULT CHARSET=utf8; 378 | /*!40101 SET character_set_client = @saved_cs_client */; 379 | 380 | -- 381 | -- Temporary view structure for view `nicer_but_slower_film_list` 382 | -- 383 | 384 | DROP TABLE IF EXISTS `nicer_but_slower_film_list`; 385 | /*!50001 DROP VIEW IF EXISTS `nicer_but_slower_film_list`*/; 386 | SET @saved_cs_client = @@character_set_client; 387 | SET character_set_client = utf8; 388 | /*!50001 CREATE VIEW `nicer_but_slower_film_list` AS SELECT 389 | 1 AS `FID`, 390 | 1 AS `title`, 391 | 1 AS `description`, 392 | 1 AS `category`, 393 | 1 AS `price`, 394 | 1 AS `length`, 395 | 1 AS `rating`, 396 | 1 AS `actors`*/; 397 | SET character_set_client = @saved_cs_client; 398 | 399 | -- 400 | -- Table structure for table `payment` 401 | -- 402 | 403 | DROP TABLE IF EXISTS `payment`; 404 | /*!40101 SET @saved_cs_client = @@character_set_client */; 405 | /*!40101 SET character_set_client = utf8 */; 406 | CREATE TABLE `payment` ( 407 | `payment_id` smallint(5) unsigned NOT NULL AUTO_INCREMENT, 408 | `customer_id` smallint(5) unsigned NOT NULL, 409 | `staff_id` tinyint(3) unsigned NOT NULL, 410 | `rental_id` int(11) DEFAULT NULL, 411 | `amount` decimal(5,2) NOT NULL, 412 | `payment_date` datetime NOT NULL, 413 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 414 | PRIMARY KEY (`payment_id`), 415 | KEY `idx_fk_staff_id` (`staff_id`), 416 | KEY `idx_fk_customer_id` (`customer_id`), 417 | KEY `fk_payment_rental` (`rental_id`), 418 | CONSTRAINT `fk_payment_customer` FOREIGN KEY (`customer_id`) REFERENCES `customer` (`customer_id`) ON UPDATE CASCADE, 419 | CONSTRAINT `fk_payment_rental` FOREIGN KEY (`rental_id`) REFERENCES `rental` (`rental_id`) ON DELETE SET NULL ON UPDATE CASCADE, 420 | CONSTRAINT `fk_payment_staff` FOREIGN KEY (`staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 421 | ) ENGINE=InnoDB AUTO_INCREMENT=16050 DEFAULT CHARSET=utf8; 422 | /*!40101 SET character_set_client = @saved_cs_client */; 423 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 424 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 425 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 426 | /*!50003 SET character_set_client = utf8 */ ; 427 | /*!50003 SET character_set_results = utf8 */ ; 428 | /*!50003 SET collation_connection = utf8_general_ci */ ; 429 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 430 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 431 | DELIMITER ;; 432 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER payment_date BEFORE INSERT ON payment 433 | 434 | FOR EACH ROW SET NEW.payment_date = NOW() */;; 435 | DELIMITER ; 436 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 437 | /*!50003 SET character_set_client = @saved_cs_client */ ; 438 | /*!50003 SET character_set_results = @saved_cs_results */ ; 439 | /*!50003 SET collation_connection = @saved_col_connection */ ; 440 | 441 | -- 442 | -- Table structure for table `rental` 443 | -- 444 | 445 | DROP TABLE IF EXISTS `rental`; 446 | /*!40101 SET @saved_cs_client = @@character_set_client */; 447 | /*!40101 SET character_set_client = utf8 */; 448 | CREATE TABLE `rental` ( 449 | `rental_id` int(11) NOT NULL AUTO_INCREMENT, 450 | `rental_date` datetime NOT NULL, 451 | `inventory_id` mediumint(8) unsigned NOT NULL, 452 | `customer_id` smallint(5) unsigned NOT NULL, 453 | `return_date` datetime DEFAULT NULL, 454 | `staff_id` tinyint(3) unsigned NOT NULL, 455 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 456 | PRIMARY KEY (`rental_id`), 457 | UNIQUE KEY `rental_date` (`rental_date`,`inventory_id`,`customer_id`), 458 | KEY `idx_fk_inventory_id` (`inventory_id`), 459 | KEY `idx_fk_customer_id` (`customer_id`), 460 | KEY `idx_fk_staff_id` (`staff_id`), 461 | CONSTRAINT `fk_rental_customer` FOREIGN KEY (`customer_id`) REFERENCES `customer` (`customer_id`) ON UPDATE CASCADE, 462 | CONSTRAINT `fk_rental_inventory` FOREIGN KEY (`inventory_id`) REFERENCES `inventory` (`inventory_id`) ON UPDATE CASCADE, 463 | CONSTRAINT `fk_rental_staff` FOREIGN KEY (`staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 464 | ) ENGINE=InnoDB AUTO_INCREMENT=16050 DEFAULT CHARSET=utf8; 465 | /*!40101 SET character_set_client = @saved_cs_client */; 466 | /*!50003 SET @saved_cs_client = @@character_set_client */ ; 467 | /*!50003 SET @saved_cs_results = @@character_set_results */ ; 468 | /*!50003 SET @saved_col_connection = @@collation_connection */ ; 469 | /*!50003 SET character_set_client = utf8 */ ; 470 | /*!50003 SET character_set_results = utf8 */ ; 471 | /*!50003 SET collation_connection = utf8_general_ci */ ; 472 | /*!50003 SET @saved_sql_mode = @@sql_mode */ ; 473 | /*!50003 SET sql_mode = 'STRICT_TRANS_TABLES,STRICT_ALL_TABLES,TRADITIONAL,NO_AUTO_CREATE_USER,NO_ENGINE_SUBSTITUTION' */ ; 474 | DELIMITER ;; 475 | /*!50003 CREATE*/ /*!50017 DEFINER=`root`@`localhost`*/ /*!50003 TRIGGER rental_date BEFORE INSERT ON rental 476 | 477 | FOR EACH ROW SET NEW.rental_date = NOW() */;; 478 | DELIMITER ; 479 | /*!50003 SET sql_mode = @saved_sql_mode */ ; 480 | /*!50003 SET character_set_client = @saved_cs_client */ ; 481 | /*!50003 SET character_set_results = @saved_cs_results */ ; 482 | /*!50003 SET collation_connection = @saved_col_connection */ ; 483 | 484 | -- 485 | -- Temporary view structure for view `sales_by_film_category` 486 | -- 487 | 488 | DROP TABLE IF EXISTS `sales_by_film_category`; 489 | /*!50001 DROP VIEW IF EXISTS `sales_by_film_category`*/; 490 | SET @saved_cs_client = @@character_set_client; 491 | SET character_set_client = utf8; 492 | /*!50001 CREATE VIEW `sales_by_film_category` AS SELECT 493 | 1 AS `category`, 494 | 1 AS `total_sales`*/; 495 | SET character_set_client = @saved_cs_client; 496 | 497 | -- 498 | -- Temporary view structure for view `sales_by_store` 499 | -- 500 | 501 | DROP TABLE IF EXISTS `sales_by_store`; 502 | /*!50001 DROP VIEW IF EXISTS `sales_by_store`*/; 503 | SET @saved_cs_client = @@character_set_client; 504 | SET character_set_client = utf8; 505 | /*!50001 CREATE VIEW `sales_by_store` AS SELECT 506 | 1 AS `store`, 507 | 1 AS `manager`, 508 | 1 AS `total_sales`*/; 509 | SET character_set_client = @saved_cs_client; 510 | 511 | -- 512 | -- Table structure for table `staff` 513 | -- 514 | 515 | DROP TABLE IF EXISTS `staff`; 516 | /*!40101 SET @saved_cs_client = @@character_set_client */; 517 | /*!40101 SET character_set_client = utf8 */; 518 | CREATE TABLE `staff` ( 519 | `staff_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 520 | `first_name` varchar(45) NOT NULL, 521 | `last_name` varchar(45) NOT NULL, 522 | `address_id` smallint(5) unsigned NOT NULL, 523 | `picture` blob, 524 | `email` varchar(50) DEFAULT NULL, 525 | `store_id` tinyint(3) unsigned NOT NULL, 526 | `active` tinyint(1) NOT NULL DEFAULT '1', 527 | `username` varchar(16) NOT NULL, 528 | `password` varchar(40) CHARACTER SET utf8 COLLATE utf8_bin DEFAULT NULL, 529 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 530 | PRIMARY KEY (`staff_id`), 531 | KEY `idx_fk_store_id` (`store_id`), 532 | KEY `idx_fk_address_id` (`address_id`), 533 | CONSTRAINT `fk_staff_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 534 | CONSTRAINT `fk_staff_store` FOREIGN KEY (`store_id`) REFERENCES `store` (`store_id`) ON UPDATE CASCADE 535 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 536 | /*!40101 SET character_set_client = @saved_cs_client */; 537 | 538 | -- 539 | -- Temporary view structure for view `staff_list` 540 | -- 541 | 542 | DROP TABLE IF EXISTS `staff_list`; 543 | /*!50001 DROP VIEW IF EXISTS `staff_list`*/; 544 | SET @saved_cs_client = @@character_set_client; 545 | SET character_set_client = utf8; 546 | /*!50001 CREATE VIEW `staff_list` AS SELECT 547 | 1 AS `ID`, 548 | 1 AS `name`, 549 | 1 AS `address`, 550 | 1 AS `zip code`, 551 | 1 AS `phone`, 552 | 1 AS `city`, 553 | 1 AS `country`, 554 | 1 AS `SID`*/; 555 | SET character_set_client = @saved_cs_client; 556 | 557 | -- 558 | -- Table structure for table `store` 559 | -- 560 | 561 | DROP TABLE IF EXISTS `store`; 562 | /*!40101 SET @saved_cs_client = @@character_set_client */; 563 | /*!40101 SET character_set_client = utf8 */; 564 | CREATE TABLE `store` ( 565 | `store_id` tinyint(3) unsigned NOT NULL AUTO_INCREMENT, 566 | `manager_staff_id` tinyint(3) unsigned NOT NULL, 567 | `address_id` smallint(5) unsigned NOT NULL, 568 | `last_update` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, 569 | PRIMARY KEY (`store_id`), 570 | UNIQUE KEY `idx_unique_manager` (`manager_staff_id`), 571 | KEY `idx_fk_address_id` (`address_id`), 572 | CONSTRAINT `fk_store_address` FOREIGN KEY (`address_id`) REFERENCES `address` (`address_id`) ON UPDATE CASCADE, 573 | CONSTRAINT `fk_store_staff` FOREIGN KEY (`manager_staff_id`) REFERENCES `staff` (`staff_id`) ON UPDATE CASCADE 574 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 575 | /*!40101 SET character_set_client = @saved_cs_client */; 576 | 577 | -- 578 | -- Table structure for table `test` 579 | -- 580 | 581 | DROP TABLE IF EXISTS `test`; 582 | /*!40101 SET @saved_cs_client = @@character_set_client */; 583 | /*!40101 SET character_set_client = utf8 */; 584 | CREATE TABLE `test` ( 585 | `test1` int(10) DEFAULT NULL 586 | ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COMMENT='table''s comment'; 587 | /*!40101 SET character_set_client = @saved_cs_client */; 588 | 589 | -- 590 | -- Table structure for table `test2` 591 | -- 592 | 593 | DROP TABLE IF EXISTS `test2`; 594 | /*!40101 SET @saved_cs_client = @@character_set_client */; 595 | /*!40101 SET character_set_client = utf8 */; 596 | CREATE TABLE `test2` ( 597 | `id` int(10) NOT NULL AUTO_INCREMENT, 598 | `fk` int(10) NULL, 599 | `val` decimal(11,3) NOT NULL, 600 | `texto` char(60) NOT NULL DEFAULT 'default', 601 | `datade` timestamp NULL DEFAULT NULL ON UPDATE CURRENT_TIMESTAMP, 602 | `new_field` int(10) NULL, 603 | PRIMARY KEY (`id`,`new_field`), 604 | KEY `FK__test1` (`fk`,`texto`), 605 | UNIQUE KEY `FK__test1` (`datade`), 606 | CONSTRAINT `FK__test3` FOREIGN KEY (`id`) REFERENCES `test` (`test1`) 607 | CONSTRAINT `FK__test3` FOREIGN KEY (`fk`) REFERENCES `test3` (`id`) 608 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8 ROW_FORMAT=COMPRESSED KEY_BLOCK_SIZE=4 COMMENT='test1'; 609 | /*!40101 SET character_set_client = @saved_cs_client */; 610 | 611 | -- 612 | -- Table structure for table `test3` 613 | -- 614 | 615 | DROP TABLE IF EXISTS `test3`; 616 | /*!40101 SET @saved_cs_client = @@character_set_client */; 617 | /*!40101 SET character_set_client = utf8 */; 618 | CREATE TABLE `test3` ( 619 | `id` int(11) NOT NULL AUTO_INCREMENT, 620 | PRIMARY KEY (`id`) 621 | ) ENGINE=InnoDB AUTO_INCREMENT=3 DEFAULT CHARSET=utf8; 622 | /*!40101 SET character_set_client = @saved_cs_client */; 623 | 624 | -- 625 | -- Final view structure for view `actor_info` 626 | -- 627 | 628 | /*!50001 DROP VIEW IF EXISTS `actor_info`*/; 629 | /*!50001 SET @saved_cs_client = @@character_set_client */; 630 | /*!50001 SET @saved_cs_results = @@character_set_results */; 631 | /*!50001 SET @saved_col_connection = @@collation_connection */; 632 | /*!50001 SET character_set_client = utf8 */; 633 | /*!50001 SET character_set_results = utf8 */; 634 | /*!50001 SET collation_connection = utf8_general_ci */; 635 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 636 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY INVOKER */ 637 | /*!50001 VIEW `actor_info` AS select `a`.`actor_id` AS `actor_id`,`a`.`first_name` AS `first_name`,`a`.`last_name` AS `last_name`,group_concat(distinct concat(`c`.`name`,': ',(select group_concat(`f`.`title` order by `f`.`title` ASC separator ', ') from ((`film` `f` join `film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `film_actor` `fa` on((`f`.`film_id` = `fa`.`film_id`))) where ((`fc`.`category_id` = `c`.`category_id`) and (`fa`.`actor_id` = `a`.`actor_id`)))) order by `c`.`name` ASC separator '; ') AS `film_info` from (((`actor` `a` left join `film_actor` `fa` on((`a`.`actor_id` = `fa`.`actor_id`))) left join `film_category` `fc` on((`fa`.`film_id` = `fc`.`film_id`))) left join `category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `a`.`actor_id`,`a`.`first_name`,`a`.`last_name` */; 638 | /*!50001 SET character_set_client = @saved_cs_client */; 639 | /*!50001 SET character_set_results = @saved_cs_results */; 640 | /*!50001 SET collation_connection = @saved_col_connection */; 641 | 642 | -- 643 | -- Final view structure for view `customer_list` 644 | -- 645 | 646 | /*!50001 DROP VIEW IF EXISTS `customer_list`*/; 647 | /*!50001 SET @saved_cs_client = @@character_set_client */; 648 | /*!50001 SET @saved_cs_results = @@character_set_results */; 649 | /*!50001 SET @saved_col_connection = @@collation_connection */; 650 | /*!50001 SET character_set_client = utf8 */; 651 | /*!50001 SET character_set_results = utf8 */; 652 | /*!50001 SET collation_connection = utf8_general_ci */; 653 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 654 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 655 | /*!50001 VIEW `customer_list` AS select `cu`.`customer_id` AS `ID`,concat(`cu`.`first_name`,_utf8' ',`cu`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`city`.`city` AS `city`,`country`.`country` AS `country`,if(`cu`.`active`,_utf8'active',_utf8'') AS `notes`,`cu`.`store_id` AS `SID` from (((`customer` `cu` join `address` `a` on((`cu`.`address_id` = `a`.`address_id`))) join `city` on((`a`.`city_id` = `city`.`city_id`))) join `country` on((`city`.`country_id` = `country`.`country_id`))) */; 656 | /*!50001 SET character_set_client = @saved_cs_client */; 657 | /*!50001 SET character_set_results = @saved_cs_results */; 658 | /*!50001 SET collation_connection = @saved_col_connection */; 659 | 660 | -- 661 | -- Final view structure for view `film_list` 662 | -- 663 | 664 | /*!50001 DROP VIEW IF EXISTS `film_list`*/; 665 | /*!50001 SET @saved_cs_client = @@character_set_client */; 666 | /*!50001 SET @saved_cs_results = @@character_set_results */; 667 | /*!50001 SET @saved_col_connection = @@collation_connection */; 668 | /*!50001 SET character_set_client = utf8 */; 669 | /*!50001 SET character_set_results = utf8 */; 670 | /*!50001 SET collation_connection = utf8_general_ci */; 671 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 672 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 673 | /*!50001 VIEW `film_list` AS select `film`.`film_id` AS `FID`,`film`.`title` AS `title`,`film`.`description` AS `description`,`category`.`name` AS `category`,`film`.`rental_rate` AS `price`,`film`.`length` AS `length`,`film`.`rating` AS `rating`,group_concat(concat(`actor`.`first_name`,_utf8' ',`actor`.`last_name`) separator ', ') AS `actors` from ((((`category` left join `film_category` on((`category`.`category_id` = `film_category`.`category_id`))) left join `film` on((`film_category`.`film_id` = `film`.`film_id`))) join `film_actor` on((`film`.`film_id` = `film_actor`.`film_id`))) join `actor` on((`film_actor`.`actor_id` = `actor`.`actor_id`))) group by `film`.`film_id`,`category`.`name` */; 674 | /*!50001 SET character_set_client = @saved_cs_client */; 675 | /*!50001 SET character_set_results = @saved_cs_results */; 676 | /*!50001 SET collation_connection = @saved_col_connection */; 677 | 678 | -- 679 | -- Final view structure for view `nicer_but_slower_film_list` 680 | -- 681 | 682 | /*!50001 DROP VIEW IF EXISTS `nicer_but_slower_film_list`*/; 683 | /*!50001 SET @saved_cs_client = @@character_set_client */; 684 | /*!50001 SET @saved_cs_results = @@character_set_results */; 685 | /*!50001 SET @saved_col_connection = @@collation_connection */; 686 | /*!50001 SET character_set_client = utf8 */; 687 | /*!50001 SET character_set_results = utf8 */; 688 | /*!50001 SET collation_connection = utf8_general_ci */; 689 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 690 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 691 | /*!50001 VIEW `nicer_but_slower_film_list` AS select `film`.`film_id` AS `FID`,`film`.`title` AS `title`,`film`.`description` AS `description`,`category`.`name` AS `category`,`film`.`rental_rate` AS `price`,`film`.`length` AS `length`,`film`.`rating` AS `rating`,group_concat(concat(concat(upper(substr(`actor`.`first_name`,1,1)),lower(substr(`actor`.`first_name`,2,length(`actor`.`first_name`))),_utf8' ',concat(upper(substr(`actor`.`last_name`,1,1)),lower(substr(`actor`.`last_name`,2,length(`actor`.`last_name`)))))) separator ', ') AS `actors` from ((((`category` left join `film_category` on((`category`.`category_id` = `film_category`.`category_id`))) left join `film` on((`film_category`.`film_id` = `film`.`film_id`))) join `film_actor` on((`film`.`film_id` = `film_actor`.`film_id`))) join `actor` on((`film_actor`.`actor_id` = `actor`.`actor_id`))) group by `film`.`film_id`,`category`.`name` */; 692 | /*!50001 SET character_set_client = @saved_cs_client */; 693 | /*!50001 SET character_set_results = @saved_cs_results */; 694 | /*!50001 SET collation_connection = @saved_col_connection */; 695 | 696 | -- 697 | -- Final view structure for view `sales_by_film_category` 698 | -- 699 | 700 | /*!50001 DROP VIEW IF EXISTS `sales_by_film_category`*/; 701 | /*!50001 SET @saved_cs_client = @@character_set_client */; 702 | /*!50001 SET @saved_cs_results = @@character_set_results */; 703 | /*!50001 SET @saved_col_connection = @@collation_connection */; 704 | /*!50001 SET character_set_client = utf8 */; 705 | /*!50001 SET character_set_results = utf8 */; 706 | /*!50001 SET collation_connection = utf8_general_ci */; 707 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 708 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 709 | /*!50001 VIEW `sales_by_film_category` AS select `c`.`name` AS `category`,sum(`p`.`amount`) AS `total_sales` from (((((`payment` `p` join `rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `film` `f` on((`i`.`film_id` = `f`.`film_id`))) join `film_category` `fc` on((`f`.`film_id` = `fc`.`film_id`))) join `category` `c` on((`fc`.`category_id` = `c`.`category_id`))) group by `c`.`name` order by `total_sales` desc */; 710 | /*!50001 SET character_set_client = @saved_cs_client */; 711 | /*!50001 SET character_set_results = @saved_cs_results */; 712 | /*!50001 SET collation_connection = @saved_col_connection */; 713 | 714 | -- 715 | -- Final view structure for view `sales_by_store` 716 | -- 717 | 718 | /*!50001 DROP VIEW IF EXISTS `sales_by_store`*/; 719 | /*!50001 SET @saved_cs_client = @@character_set_client */; 720 | /*!50001 SET @saved_cs_results = @@character_set_results */; 721 | /*!50001 SET @saved_col_connection = @@collation_connection */; 722 | /*!50001 SET character_set_client = utf8 */; 723 | /*!50001 SET character_set_results = utf8 */; 724 | /*!50001 SET collation_connection = utf8_general_ci */; 725 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 726 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 727 | /*!50001 VIEW `sales_by_store` AS select concat(`c`.`city`,_utf8',',`cy`.`country`) AS `store`,concat(`m`.`first_name`,_utf8' ',`m`.`last_name`) AS `manager`,sum(`p`.`amount`) AS `total_sales` from (((((((`payment` `p` join `rental` `r` on((`p`.`rental_id` = `r`.`rental_id`))) join `inventory` `i` on((`r`.`inventory_id` = `i`.`inventory_id`))) join `store` `s` on((`i`.`store_id` = `s`.`store_id`))) join `address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `city` `c` on((`a`.`city_id` = `c`.`city_id`))) join `country` `cy` on((`c`.`country_id` = `cy`.`country_id`))) join `staff` `m` on((`s`.`manager_staff_id` = `m`.`staff_id`))) group by `s`.`store_id` order by `cy`.`country`,`c`.`city` */; 728 | /*!50001 SET character_set_client = @saved_cs_client */; 729 | /*!50001 SET character_set_results = @saved_cs_results */; 730 | /*!50001 SET collation_connection = @saved_col_connection */; 731 | 732 | -- 733 | -- Final view structure for view `staff_list` 734 | -- 735 | 736 | /*!50001 DROP VIEW IF EXISTS `staff_list`*/; 737 | /*!50001 SET @saved_cs_client = @@character_set_client */; 738 | /*!50001 SET @saved_cs_results = @@character_set_results */; 739 | /*!50001 SET @saved_col_connection = @@collation_connection */; 740 | /*!50001 SET character_set_client = utf8 */; 741 | /*!50001 SET character_set_results = utf8 */; 742 | /*!50001 SET collation_connection = utf8_general_ci */; 743 | /*!50001 CREATE ALGORITHM=UNDEFINED */ 744 | /*!50013 DEFINER=`root`@`localhost` SQL SECURITY DEFINER */ 745 | /*!50001 VIEW `staff_list` AS select `s`.`staff_id` AS `ID`,concat(`s`.`first_name`,_utf8' ',`s`.`last_name`) AS `name`,`a`.`address` AS `address`,`a`.`postal_code` AS `zip code`,`a`.`phone` AS `phone`,`city`.`city` AS `city`,`country`.`country` AS `country`,`s`.`store_id` AS `SID` from (((`staff` `s` join `address` `a` on((`s`.`address_id` = `a`.`address_id`))) join `city` on((`a`.`city_id` = `city`.`city_id`))) join `country` on((`city`.`country_id` = `country`.`country_id`))) */; 746 | /*!50001 SET character_set_client = @saved_cs_client */; 747 | /*!50001 SET character_set_results = @saved_cs_results */; 748 | /*!50001 SET collation_connection = @saved_col_connection */; 749 | /*!40103 SET TIME_ZONE=@OLD_TIME_ZONE */; 750 | 751 | /*!40101 SET SQL_MODE=@OLD_SQL_MODE */; 752 | /*!40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */; 753 | /*!40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */; 754 | /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; 755 | /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; 756 | /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; 757 | /*!40111 SET SQL_NOTES=@OLD_SQL_NOTES */; 758 | 759 | -- Dump completed on 2016-04-08 9:05:53 760 | --------------------------------------------------------------------------------