diff --git a/commands/sql/sql.drush.inc b/commands/sql/sql.drush.inc index ba457aa..71c68d4 100644 --- a/commands/sql/sql.drush.inc +++ b/commands/sql/sql.drush.inc @@ -353,6 +353,19 @@ function drush_sql_dump_execute() { } } +/** + * Construct an array that places table names in appropriate + * buckets based on whether the table is to be skipped, included + * for structure only, or have structure and data dumped. + * The keys of the array are: + * - skip: tables to be skipped completed in the dump + * - structure: tables to only have their structure i.e. DDL dumped + * - tables: tables to have structure and data dumped + * + * @return array + * An array of table names with each table name in the appropriate + * element of the array. + */ function drush_sql_get_table_selection() { // Skip large core tables if instructed. Also used by 'sql-sync' command. $skip_tables = _drush_sql_get_table_list('skip-tables'); @@ -365,6 +378,109 @@ function drush_sql_get_table_selection() { } /** + * Given the table names in the input array that may contain wildcards (`*`), + * expand the table names so that the array returned only contains valid table + * names i.e. actual tables that exist rather than table names containing a + * wildcard. + * + * @param array $table_selection + * An array of table names where the table names can contain the + * `*` wildcard character. + * @param $db_spec + * For D5/D6, a $db_url. For D7+, a target in the default DB connection. + * @param $site_record + * Necessary for remote database. + * @return array + * An array of tables with each table name in the appropriate + * element of the array. + */ +function drush_sql_expand_table_selection($table_selection, $db_spec, $site_record = NULL) { + if (isset($table_selection['skip'])) { + $table_selection['skip'] = _drush_sql_expand_and_filter_tables($table_selection['skip'], $db_spec, $site_record); + } + if (isset($table_selection['structure'])) { + $table_selection['structure'] = _drush_sql_expand_and_filter_tables($table_selection['structure'], $db_spec, $site_record); + } + if (isset($table_selection['tables'])) { + $table_selection['tables'] = _drush_sql_expand_and_filter_tables($table_selection['tables'], $db_spec, $site_record); + } + return $table_selection; +} + +/** + * Get a list of all table names and expand input that may contain + * wildcards (`*`) if necessary so that the array returned only contains valid + * table names i.e. actual tables that exist rather than table names containing + * a wildcard. + * + * @param $db_spec + * For D5/D6, a $db_url. For D7+, a target in the default DB connection. + * @param $site_record + * Necessary for remote database. + * @return array + * An array of tables with each table name in the appropriate + * element of the array. + */ +function drush_sql_get_expanded_table_selection($db_spec, $site_record = NULL) { + return drush_sql_expand_table_selection(drush_sql_get_table_selection(), $db_spec, $site_record); +} + +/** + * Expand wildcard tables. + * + * @param array $tables + * An array of table names, some of which may contain wildcards (`*`). + * @param $db_spec + * For D5/D6, a $db_url. For D7+, a target in the default DB connection. + * @param $site_record + * Necessary for remote database. + * @return + * An array with the corresponding expanded tables names. + */ +function drush_sql_expand_wildcard_tables($tables, $db_spec, $site_record = NULL) { + // Get the existing table names in the current database. + $db_tables = _drush_sql_get_db_table_list($db_spec, $site_record); + + // Table name expansion based on `*` wildcard. + $expanded_db_tables = array(); + foreach ($tables as $k => $table) { + // Only deal with table names containing a wildcard. + if (strpos($table, '*') !== FALSE) { + $pattern = '/^' . str_replace('*', '.*', $table) . '$/i'; + // Merge those existing tables which match the pattern with the rest of + // the expanded table names. + $expanded_db_tables += preg_grep($pattern, $db_tables); + } + } + return $expanded_db_tables; +} + +/** + * Filters tables. + * + * @param array $tables + * An array of table names to filter. + * @param $db_spec + * For D5/D6, a $db_url. For D7+, a target in the default DB connection. + * @return + * An array with only valid table names (i.e. all of which actually exist in + * the database). + */ +function drush_sql_filter_tables($tables, $db_spec, $site_record = NULL) { + // Get the existing table names in the current database. + $db_tables = _drush_sql_get_db_table_list($db_spec, $site_record); + + // Ensure all the tables actually exist in the database. + foreach ($tables as $k => $table) { + if (!in_array($table, $db_tables)) { + unset($tables[$k]); + } + } + + return $tables; +} + +/** * Build a mysqldump/pg_dump/sqlite statement. * * @param db_spec @@ -375,7 +491,10 @@ function drush_sql_get_table_selection() { * 2. The filepath where the dump will be saved. */ function drush_sql_dump($db_spec = NULL) { - return drush_sql_build_dump_command(drush_sql_get_table_selection(), $db_spec, drush_get_option('result-file', FALSE)); + if (is_null($db_spec)) { + $db_spec = _drush_sql_get_db_spec(); + } + return drush_sql_build_dump_command(drush_sql_get_expanded_table_selection($db_spec), $db_spec, drush_get_option('result-file', FALSE)); } /** @@ -404,10 +523,6 @@ function drush_sql_build_dump_command($table_selection, $db_spec = NULL, $file = // @todo add documention once a hook for drush_get_option_help() is available. // @see drush_get_option_help() in drush.inc $ordered_dump = drush_get_option('ordered-dump'); - - if (is_null($db_spec)) { - $db_spec = _drush_sql_get_db_spec(); - } $database = $db_spec['database']; // $file is passed in to us usually via --result-file. If the user @@ -564,6 +679,30 @@ function drush_sql_build_dump_command($table_selection, $db_spec = NULL, $file = } /** + * Given the table names in the input array that may contain wildcards (`*`), + * expand the table names so that the array returned only contains table names + * that exist in the database. + * + * @param array $tables + * An array of table names where the table names may contain the + * `*` wildcard character. + * @param $db_spec + * For D5/D6, a $db_url. For D7+, a target in the default DB connection. + * @param $site_record + * Necessary for remote database. + * @return array + * An array of tables with each table name in the appropriate + * element of the array. + */ +function _drush_sql_expand_and_filter_tables($tables, $db_spec, $site_record = NULL) { + $expanded_tables = drush_sql_expand_wildcard_tables($tables, $db_spec, $site_record); + $tables = drush_sql_filter_tables($tables + $expanded_tables, $db_spec); + $tables = array_unique($tables); + sort($tables); + return $tables; +} + +/** * Consult the specified options and return the list of tables * specified. * @@ -603,9 +742,91 @@ function _drush_sql_get_table_list($option_name) { } /** - * Command callback. Executes the given SQL query on the Drupal database. + * Extract the name of all existing tables in the given database. + * + * @param $db_spec + * For D5/D6, a $db_url. For D7, a target in the default DB connection. + * @param $site_record + * Necessary for remote database. + * @return array + * An array of table names which exist in the current database. */ +function _drush_sql_get_db_table_list($db_spec, $site_record = NULL) { + $target_site = '@self'; + // Verify the details of the remote host. + if (isset($db_spec['remote-host'])) { + if (is_null($site_record)) { + return drush_set_error('DRUSH_SQL_NO_SITE_ALIAS', dt('Retrieving the table list for a remote DB, but the site record is missing.')); + } + $target_site = $site_record; + } + // Prepare the query to obtain the list of tables depending on the + // database type. + $suffix = ''; + $scheme = _drush_sql_get_scheme($db_spec); + switch ($scheme) { + case 'pgsql': + $query = drush_sql_show_tables_pgsql(); + break; + case 'sqlite': + $query = '.tables'; + break; + case 'sqlsrv': + $query = 'SELECT TABLE_NAME FROM information_schema.tables'; + break; + case 'oracle': + $query = "SELECT TABLE_NAME FROM USER_TABLES WHERE TABLE_NAME NOT IN ('BLOBS','LONG_IDENTIFIERS')"; + $suffix = '.sql'; + break; + default: + $query = 'SHOW TABLES'; + break; + } + + $result = drush_invoke_process($target_site, 'sqlq', array($query), array(), array('override-simulated' => TRUE, 'integrate' => FALSE)); + // Save $query to a tmp file if needed. We will redirect it in. + $tables_raw = explode("\n", rtrim($result['output'])); + // Shift off the "Calling system(…);" line at the top of the output. + array_shift($tables_raw); + + $tables = array(); + if (!empty($tables_raw)) { + if ($scheme === 'sqlite') { + // SQLite's '.tables' command always outputs the table names in a column + // format, like this: + // table_alpha table_charlie table_echo + // table_bravo table_delta table_foxtrot + // …and there doesn't seem to be a way to fix that. So we need to do some + // clean-up. + foreach ($tables_raw as $line) { + preg_match_all('/[^\s]+/', $line, $matches); + if (!empty($matches[0])) { + foreach ($matches[0] as $match) { + $tables[] = $match; + } + } + } + } + elseif ($scheme === 'sqlsrv') { + // Shift off the header of the column of data returned. + array_pop($tables_raw); + array_pop($tables_raw); + $tables = $tables_raw; + } + else { + // Shift off the header of the column of data returned. + array_shift($tables_raw); + $tables = $tables_raw; + } + } + + return $tables; +} + +/** + * Command callback. Executes the given SQL query on the Drupal database. + */ function drush_sql_query($query = NULL) { drush_sql_bootstrap_further(); $filename = drush_get_option('file', NULL); @@ -616,7 +837,7 @@ function drush_sql_query($query = NULL) { return _drush_sql_query($query, NULL, $filename); } -/* +/** * Execute a SQL query. * * @param string $query @@ -645,7 +866,7 @@ function _drush_sql_query($query, $db_spec = NULL, $filename = NULL) { } } - // is this an oracle query + // Is this an oracle query? if ($scheme == 'oracle') { $query = drush_sql_format_oracle($query); $suffix = '.sql'; @@ -683,6 +904,9 @@ function _drush_sql_query($query, $db_spec = NULL, $filename = NULL) { return (drush_op_system($exec) == 0); } +/** + * Drops all tables in the database. + */ function drush_sql_drop() { if (!drush_confirm(dt('Do you really want to drop all tables?'))) { return drush_user_abort(); @@ -696,56 +920,15 @@ function drush_sql_drop() { // is rewritten to also use that technique, it should maintain // the drop tables code here as a fallback. function _drush_sql_drop($db_spec = NULL) { - // TODO: integrate with _drush_sql_get_table_list? - - $suffix = ''; + $tables = _drush_sql_get_db_table_list($db_spec); $scheme = _drush_sql_get_scheme($db_spec); - switch ($scheme) { - case 'pgsql': - $query = drush_sql_show_tables_pgsql(); - break; - case 'sqlite': - $query = '.tables'; - break; - case 'sqlsrv': - $query = 'SELECT TABLE_NAME FROM information_schema.tables'; - break; - case 'oracle': - $query = "SELECT TABLE_NAME FROM USER_TABLES WHERE TABLE_NAME NOT IN ('BLOBS','LONG_IDENTIFIERS')"; - $suffix = '.sql'; - break; - default: - $query = 'SHOW TABLES;'; - } - - $filename = drush_save_data_to_temp_file($query, $suffix); - $exec = drush_sql_build_exec($db_spec, $filename); - - // Actually run this prep query no matter if in SIMULATE. - $old = drush_get_context('DRUSH_SIMULATE'); - drush_set_context('DRUSH_SIMULATE', FALSE); - drush_shell_exec($exec); - drush_set_context('DRUSH_SIMULATE', $old); - if ($tables = drush_shell_exec_output()) { + if (count($tables)) { if ($scheme === 'sqlite') { - // SQLite's '.tables' command always outputs the table names in a column - // format, like this: - // table_alpha table_charlie table_echo - // table_bravo table_delta table_foxtrot - // …and there doesn't seem to be a way to fix that. So we need to do some - // clean-up. - // Since we're already doing iteration here, might as well build the SQL - // too, since SQLite only wants one table per DROP TABLE command (so we have - // to do "DROP TABLE foo; DROP TABLE bar;" instead of - // "DROP TABLE foo, bar;"). $sql = ''; - foreach ($tables as $line) { - preg_match_all('/[^\s]+/', $line, $matches); - if (!empty($matches[0])) { - foreach ($matches[0] as $match) { - $sql .= "DROP TABLE {$match};"; - } - } + // SQLite only wants one table per DROP TABLE command (so we have to do + // "DROP TABLE foo; DROP TABLE bar;" instead of "DROP TABLE foo, bar;"). + foreach ($tables as $table) { + $sql .= "DROP TABLE {$match};"; } // We can't use drush_op('db_query', $sql) because it will only perform one // SQL command and we're technically performing several. @@ -753,16 +936,7 @@ function _drush_sql_drop($db_spec = NULL) { $exec .= " '{$sql}'"; return drush_op_system($exec) == 0; } - elseif ($scheme === 'sqlsrv') { - // Shift off the header of the column of data returned. - array_pop($tables); - array_pop($tables); - $sql = 'DROP TABLE '. implode(', ', $tables); - return _drush_sql_query($sql, $db_spec); - } else { - // Shift off the header of the column of data returned. - array_shift($tables); $sql = 'DROP TABLE '. implode(', ', $tables); return _drush_sql_query($sql, $db_spec); } diff --git a/examples/example.drushrc.php b/examples/example.drushrc.php index 3715651..e144c0a 100644 --- a/examples/example.drushrc.php +++ b/examples/example.drushrc.php @@ -263,7 +263,7 @@ * commands when the "--structure-tables-key=common" option is provided. * You may add specific tables to the existing array or add a new element. */ -# $options['structure-tables']['common'] = array('cache', 'cache_filter', 'cache_menu', 'cache_page', 'history', 'sessions', 'watchdog'); +# $options['structure-tables']['common'] = array('cache*', 'history', 'search_*', 'sessions', 'watchdog'); /** * List of tables to be omitted entirely from SQL dumps made by the 'sql-dump' diff --git a/includes/drush.inc b/includes/drush.inc index 0ed75fd..485a9e7 100644 --- a/includes/drush.inc +++ b/includes/drush.inc @@ -320,7 +320,7 @@ function drush_get_global_options($brief = FALSE) { $options['debug'] = array('short-form' => 'd', 'context' => 'DRUSH_DEBUG', 'description' => 'Display even more information, including internal messages.'); $options['yes'] = array('short-form' => 'y', 'context' => 'DRUSH_AFFIRMATIVE', 'description' => "Assume 'yes' as answer to all prompts."); $options['no'] = array('short-form' => 'n', 'context' => 'DRUSH_NEGATIVE', 'description' => "Assume 'no' as answer to all prompts."); - $options['simulate'] = array('short-form' => 's', 'context' => 'DRUSH_SIMULATE', 'description' => "Simulate all relevant actions (don't actually change the system)."); + $options['simulate'] = array('short-form' => 's', 'context' => 'DRUSH_SIMULATE', 'never-propagate' => TRUE, 'description' => "Simulate all relevant actions (don't actually change the system)."); $options['pipe'] = array('short-form' => 'p', 'hidden' => TRUE, 'description' => "Emit a compact representation of the command for scripting."); $options['help'] = array('short-form' => 'h', 'description' => "This help system."); $options['version'] = array('description' => "Show drush version."); diff --git a/tests/sqlDumpTest.php b/tests/sqlDumpTest.php new file mode 100644 index 0000000..a0d8321 --- /dev/null +++ b/tests/sqlDumpTest.php @@ -0,0 +1,264 @@ +setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $options = array( + 'result-file' => $dump_file_path, + ); + $this->createDumpFile($options); + $this->assertFileExists($dump_file_path); + } + + /** + * Test that a compressed dump file is created successfuly. + * Dependent on gzip being in the PATH. + */ + public function testCompressedDumpFileCreation() { + $sites = $this->setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $dump_file_arg_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $gzip_dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql.gz'; + $options = array( + 'result-file' => $dump_file_arg_path, + 'gzip' => TRUE, + ); + $this->createDumpFile($options); + $this->assertFileExists($gzip_dump_file_path); + } + + /** + * Test that a dump file created by the sql-dump command can be + * successfully loaded. + */ + public function testLoadingDumpFile() { + $sites = $this->setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $options = array( + 'result-file' => $dump_file_path, + ); + $this->createDumpFile($options); + // Retrieve list of tables in the database. + $orig_list_of_tables = $this->getTableList(); + // Drop all tables. + $this->dropAllTables(); + // Recreate those tables. + $this->executeQuery(NULL, array('file' => $dump_file_path)); + // Retrieve list of tables in the database. + $latest_list_of_tables = $this->getTableList(); + $this->assertEquals($orig_list_of_tables, $latest_list_of_tables, 'dump created all tables'); + } + + /** + * Test that the skip tables option works. + */ + public function testSkipTables() { + $sites = $this->setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $options = array( + 'result-file' => $dump_file_path, + // Skip the watchdog table. + 'skip-tables-list' => 'watchdog' + ); + $this->createDumpFile($options); + $this->assertFileExists($dump_file_path); + // Truncate the watchdog table. + $this->executeQuery('truncate table watchdog'); + // Load dump file. + $this->executeQuery(NULL, array('file' => $dump_file_path)); + // Verify watchdog table contains no rows. + $new_row_count = $this->executeQuery('select count(*) from watchdog'); + $this->assertEquals(0, $new_row_count, 'watchdog table should be empty'); + } + + /** + * Test basic wildcard functionality. + * This is a MySQL specific test. + */ + public function testWildCardTables() { + $sites = $this->setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $alias_contents = <<webroot() . '/sites/' . key($sites) . '/drushrc.php', $alias_contents); + $dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $options = array( + 'result-file' => $dump_file_path, + 'skip-tables-key' => 'cache-tables', + ); + $this->createDumpFile($options); + // Retrieve list of cache tables in the database. + $orig_list_of_tables = $this->getTableList("'cache%'"); + // Drop all tables. + $this->dropAllTables(); + // Recreate those tables. + $this->executeQuery(NULL, array('file' => $dump_file_path)); + // Retrieve list of tables in the database. + $latest_list_of_tables = $this->getTableList("'cache%'"); + // None of the cache* tables should have been created. + $this->assertNotEquals($orig_list_of_tables, $latest_list_of_tables); + } + + /** + * Test with more tables specified with wildcard characters. + */ + public function testMoreWildCardtables() { + $sites = $this->setUpDrupal(1, TRUE, UNISH_DRUPAL_MAJOR_VERSION, 'standard'); + $alias_contents = <<webroot() . '/sites/' . key($sites) . '/drushrc.php', $alias_contents); + $dump_file_path = $this->webroot() . '/sites/' . key($sites) . '/files/createddumpfile.sql'; + $options = array( + 'result-file' => $dump_file_path, + 'skip-tables-key' => 'common', + ); + $this->createDumpFile($options); + // Retrieve list of cache tables in the database. + $orig_cache_tables = $this->getTableList("'cache%'"); + // Retrieve list of search tables in the database. + $orig_search_tables = $this->getTableList("'search_%'"); + // Drop all tables. + $this->dropAllTables(); + // Recreate those tables. + $this->executeQuery(NULL, array('file' => $dump_file_path)); + // Retrieve list of cache tables in the database. + $latest_cache_tables = $this->getTableList("'cache%'"); + // Retrieve list of search tables in the database. + $latest_search_tables = $this->getTableList("'search_%'"); + // None of the cache* tables should have been created. + $this->assertNotEquals($orig_cache_tables, $latest_cache_tables); + // None of the search_* tables should have been created. + $this->assertNotEquals($orig_search_tables, $latest_search_tables); + } + + /** + * Helper function to create a dump file with the sql-dump + * command with the given options. + * + * @param array options + * Additional options for the sql-dump command + */ + protected function createDumpFile($options) { + $base_options = array( + 'root' => $this->webroot(), + 'uri' => 'dev', + 'yes' => NULL, + ); + $this->drush('sql-dump', array(), array_merge($base_options, $options)); + } + + /** + * Helper function to execute the given query with the sql-query command + * and return the query output. + * + * @param string query + * SQL query to execute + * @param array options + * Additional options to pass to sql-query command + * @return string + * The query output + */ + protected function executeQuery($query, $options = array()) { + $base_options = array( + 'root' => $this->webroot(), + 'uri' => 'dev', + 'yes' => NULL, + ); + $scheme = $this->getDatabaseScheme(); + switch ($scheme) { + case 'pgsql': + // PostgreSQL-specific option to skip header output. + $base_options['extra'] = '--tuples-only'; + break; + case 'mysql': + case 'mysqli': + // MySQL-specific option to skip header output. + $base_options['extra'] = '--skip-column-names'; + break; + default: + break; + } + $this->drush('sql-query', array($query), array_merge($base_options, $options)); + return $this->getOutput(); + } + + /** + * @return string + * the database driver currently in use. + */ + protected function getDatabaseScheme() { + $url = parse_url(UNISH_DB_URL); + return $url['scheme']; + } + + /** + * Construct the appropriate query for the database driver in use + * to obtain a list of tables. + * + * @param string $wildcard + * Optional wildcard to apply to limit list of tables + * @return string + * List of tables + */ + protected function getTableList($wildcard = NULL) { + $scheme = $this->getDatabaseScheme(); + $condition = is_null($wildcard) ? '' : 'LIKE ' . $wildcard; + switch ($scheme) { + case 'pgsql': + $query = "SELECT tablename FROM pg_tables WHERE schemaname = 'public'"; + if (!is_null($wildcard)) { + $query .= ' AND tablename ' . $condition; + } + break; + case 'sqlite': + $query = '.tables'; + if (!is_null($wildcard)) { + // Syntax for sqlite is .tables ?PATTERN? + $query .= ' ' . $wildcard; + } + break; + case 'sqlsrv': + $query = 'SELECT table_name FROM information_schema.tables'; + if (!is_null($wildcard)) { + $query .= ' WHERE table_name ' . $condition; + } + break; + case 'oracle': + $query = "SELECT table_name FROM user_tables WHERE table_name NOT IN ('BLOBS','LONG_IDENTIFIERS')"; + if (!is_null($wildcard)) { + $query .= ' AND table_name ' . $condition; + } + break; + default: + $query = 'SHOW TABLES ' . $condition; + break; + } + return $this->executeQuery($query); + } + + /** + * Drop all tables using the sql-drop command. + */ + protected function dropAllTables() { + $base_options = array( + 'root' => $this->webroot(), + 'uri' => 'dev', + 'yes' => NULL, + ); + $this->drush('sql-drop', array(), $base_options); + } + +}