Index: includes/database.mysql-common.inc =================================================================== RCS file: /cvs/drupal/drupal/includes/database.mysql-common.inc,v retrieving revision 1.10 diff -u -F^f -r1.10 database.mysql-common.inc --- includes/database.mysql-common.inc 4 Sep 2007 21:10:45 -0000 1.10 +++ includes/database.mysql-common.inc 6 Sep 2007 22:07:08 -0000 @@ -7,11 +7,6 @@ */ /** - * @ingroup schemaapi - * @{ - */ - -/** * Runs a basic query in the active database. * * User-supplied arguments to the query should be passed in as separate @@ -48,6 +43,11 @@ function db_query($query) { } /** + * @ingroup schemaapi + * @{ + */ + +/** * Generate SQL to create a new table from a Drupal schema definition. * * @param $name @@ -71,16 +71,9 @@ function db_create_table_sql($name, $tab } // Process keys & indexes. - if (!empty($table['primary key'])) { - $sql .= " PRIMARY KEY (". _db_create_key_sql($table['primary key']) ."), \n"; - } - if (!empty($table['unique keys'])) { - foreach ($table['unique keys'] as $key => $fields) - $sql .= " UNIQUE KEY $key (". _db_create_key_sql($fields) ."), \n"; - } - if (!empty($table['indexes'])) { - foreach ($table['indexes'] as $index => $fields) - $sql .= " INDEX $index (". _db_create_key_sql($fields) ."), \n"; + $keys = _db_create_keys_sql($table); + if (count($keys)) { + $sql .= implode(", \n", $keys) .", \n"; } // Remove the last comma and space. @@ -91,6 +84,26 @@ function db_create_table_sql($name, $tab return array($sql); } +function _db_create_keys_sql($spec) { + $keys = array(); + + if (!empty($spec['primary key'])) { + $keys[] = 'PRIMARY KEY ('. _db_create_key_sql($spec['primary key']) .')'; + } + if (!empty($spec['unique keys'])) { + foreach ($spec['unique keys'] as $key => $fields) { + $keys[] = 'UNIQUE KEY '. $key .' ('. _db_create_key_sql($fields) .')'; + } + } + if (!empty($spec['indexes'])) { + foreach ($spec['indexes'] as $index => $fields) { + $keys[] = 'INDEX '. $index .' ('. _db_create_key_sql($fields) .')'; + } + } + + return $keys; +} + function _db_create_key_sql($fields) { $ret = array(); foreach ($fields as $field) { @@ -427,14 +440,49 @@ function db_drop_index(&$ret, $table, $n /** * Change a field definition. * - * IMPORTANT NOTE: On some database systems (notably PostgreSQL), - * changing a field definition involves adding a new field and - * dropping an old one. This means that any indices, primary keys and - * sequences (from serial-type fields) that use the field to be - * changed get dropped. For database portability, you MUST drop them - * explicitly before calling db_change_field() and then re-create them - * afterwards. Use db_{add,drop}_{primary_key,unique_key,index} for - * this purpose. + * IMPORTANT NOTE: To maintain database portability, you have to explicitly + * recreate all indices and primary keys that are using the changed field. + * + * That means that you have to drop all affected keys and indexes with + * db_drop_{primary_key,unique_key,index}() before calling db_change_field(). + * To recreate the keys and indices, pass the key definitions as the + * optional $new_keys argument directly to db_change_field(). + * + * For example, suppose you have: + * @code + * $schema['foo'] = array( + * 'fields' => array( + * 'bar' => array('type' => 'int', 'not null' => TRUE) + * ), + * 'primary key' => array('bar') + * ); + * @endcode + * and you want to change foo.bar to be type serial, leaving it as the + * primary key. The correct sequence is: + * @code + * db_drop_primary_key($ret, 'foo'); + * db_change_field($ret, 'foo', 'bar', 'bar', + * array('type' => 'serial', 'not null' => TRUE), + * array('primary key' => array('bar'))); + * @endcode + * + * The reasons for this are due to the different database engines: + * + * On PostgreSQL, changing a field definition involves adding a new field + * and dropping an old one which* causes any indices, primary keys and + * sequences (from serial-type fields) that use the changed field to be dropped. + * + * On MySQL, all type 'serial' fields must be part of at least one key + * or index as soon as they are created. You cannot use + * db_add_{primary_key,unique_key,index}() for this purpose because + * the ALTER TABLE command will fail to add the column without a key + * or index specification. The solution is to use the optional + * $new_keys argument to create the key or index at the same time as + * field. + * + * You could use db_add_{primary_key,unique_key,index}() in all cases + * unless you are converting a field to be type serial. You can use + * the $new_keys argument in all cases. * * @param $ret * Array to which query results will be added. @@ -446,10 +494,19 @@ function db_drop_index(&$ret, $table, $n * New name for the field (set to the same as $field if you don't want to change the name). * @param $spec * The field specification for the new field. + * @param $new_keys + * Optional keys and indexes specification to be created on the + * table along with changing the field. The format is the same as a + * table specification but without the 'fields' element. */ -function db_change_field(&$ret, $table, $field, $field_new, $spec) { - $ret[] = update_sql("ALTER TABLE {". $table ."} CHANGE $field ". - _db_create_field_sql($field_new, _db_process_field($spec))); + +function db_change_field(&$ret, $table, $field, $field_new, $spec, $new_keys = array()) { + $sql = 'ALTER TABLE {'. $table .'} CHANGE '. $field . + _db_create_field_sql($field_new, _db_process_field($spec)); + if (count($new_keys)) { + $sql .= ', ADD '.implode(', ADD ', _db_create_keys_sql($new_keys)); + } + $ret[] = update_sql($sql); } /** @@ -469,6 +526,10 @@ function db_update_field(&$ret, $table, } /** + * @} End of "ingroup schemaapi". + */ + +/** * Returns the last insert id. * * @param $table @@ -479,7 +540,3 @@ function db_update_field(&$ret, $table, function db_last_insert_id($table, $field) { return db_result(db_query('SELECT LAST_INSERT_ID()')); } - -/** - * @} End of "ingroup schemaapi". - */ Index: includes/database.pgsql.inc =================================================================== RCS file: /cvs/drupal/drupal/includes/database.pgsql.inc,v retrieving revision 1.58 diff -u -F^f -r1.58 database.pgsql.inc --- includes/database.pgsql.inc 4 Sep 2007 21:10:45 -0000 1.58 +++ includes/database.pgsql.inc 6 Sep 2007 22:07:09 -0000 @@ -831,14 +831,49 @@ function db_drop_index(&$ret, $table, $n /** * Change a field definition. * - * IMPORTANT NOTE: On some database systems (notably PostgreSQL), - * changing a field definition involves adding a new field and - * dropping an old one. This means that any indices, primary keys and - * sequences (from serial-type fields) that use the field to be - * changed get dropped. For database portability, you MUST drop them - * explicitly before calling db_change_field() and then re-create them - * afterwards. Use db_{add,drop}_{primary_key,unique_key,index} for - * this purpose. + * IMPORTANT NOTE: To maintain database portability, you have to explicitly + * recreate all indices and primary keys that are using the changed field. + * + * That means that you have to drop all affected keys and indexes with + * db_drop_{primary_key,unique_key,index}() before calling db_change_field(). + * To recreate the keys and indices, pass the key definitions as the + * optional $new_keys argument directly to db_change_field(). + * + * For example, suppose you have: + * @code + * $schema['foo'] = array( + * 'fields' => array( + * 'bar' => array('type' => 'int', 'not null' => TRUE) + * ), + * 'primary key' => array('bar') + * ); + * @endcode + * and you want to change foo.bar to be type serial, leaving it as the + * primary key. The correct sequence is: + * @code + * db_drop_primary_key($ret, 'foo'); + * db_change_field($ret, 'foo', 'bar', 'bar', + * array('type' => 'serial', 'not null' => TRUE), + * array('primary key' => array('bar'))); + * @endcode + * + * The reasons for this are due to the different database engines: + * + * On PostgreSQL, changing a field definition involves adding a new field + * and dropping an old one which* causes any indices, primary keys and + * sequences (from serial-type fields) that use the changed field to be dropped. + * + * On MySQL, all type 'serial' fields must be part of at least one key + * or index as soon as they are created. You cannot use + * db_add_{primary_key,unique_key,index}() for this purpose because + * the ALTER TABLE command will fail to add the column without a key + * or index specification. The solution is to use the optional + * $new_keys argument to create the key or index at the same time as + * field. + * + * You could use db_add_{primary_key,unique_key,index}() in all cases + * unless you are converting a field to be type serial. You can use + * the $new_keys argument in all cases. * * @param $ret * Array to which query results will be added. @@ -850,17 +885,39 @@ function db_drop_index(&$ret, $table, $n * New name for the field (set to the same as $field if you don't want to change the name). * @param $spec * The field specification for the new field. + * @param $new_keys + * Optional keys and indexes specification to be created on the + * table along with changing the field. The format is the same as a + * table specification but without the 'fields' element. */ -function db_change_field(&$ret, $table, $field, $field_new, $spec) { +function db_change_field(&$ret, $table, $field, $field_new, $spec, $new_keys = array()) { $ret[] = update_sql("ALTER TABLE {". $table ."} RENAME $field TO ". $field ."_old"); $not_null = isset($spec['not null']) ? $spec['not null'] : FALSE; unset($spec['not null']); + db_add_field($ret, $table, "$field_new", $spec); + $ret[] = update_sql("UPDATE {". $table ."} SET $field_new = ". $field ."_old"); + if ($not_null) { $ret[] = update_sql("ALTER TABLE {". $table ."} ALTER $field_new SET NOT NULL"); } + db_drop_field($ret, $table, $field .'_old'); + + if (isset($new_keys['primary key'])) { + db_add_primary_key($ret, $table, $new_keys['primary key']); + } + if (isset($new_keys['unique keys'])) { + foreach ($new_keys['unique keys'] as $name => $fields) { + db_add_unique_key($ret, $table, $name, $fields); + } + } + if (isset($new_keys['indexes'])) { + foreach ($new_keys['indexes'] as $name => $fields) { + db_add_index($ret, $table, $name, $fields); + } + } } /**