ALTER [IGNORE] TABLEtbl_name[alter_specification[,alter_specification] ...]alter_specification:table_options| ADD [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | ADD [COLUMN] (col_namecolumn_definition,...) | ADD {INDEX|KEY} [index_name] [index_type] (index_col_name,...) [index_type] | ADD [CONSTRAINT [symbol]] PRIMARY KEY [index_type] (index_col_name,...) [index_type] | ADD [CONSTRAINT [symbol]] UNIQUE [INDEX|KEY] [index_name] [index_type] (index_col_name,...) [index_type] | ADD [FULLTEXT|SPATIAL] [INDEX|KEY] [index_name] (index_col_name,...) [index_type] | ADD [CONSTRAINT [symbol]] FOREIGN KEY [index_name] (index_col_name,...)reference_definition| ALTER [COLUMN]col_name{SET DEFAULTliteral| DROP DEFAULT} | CHANGE [COLUMN]old_col_namenew_col_namecolumn_definition[FIRST|AFTERcol_name] | MODIFY [COLUMN]col_namecolumn_definition[FIRST | AFTERcol_name] | DROP [COLUMN]col_name| DROP PRIMARY KEY | DROP {INDEX|KEY}index_name| DROP FOREIGN KEYfk_symbol| DISABLE KEYS | ENABLE KEYS | RENAME [TO|AS]new_tbl_name| ORDER BYcol_name[,col_name] ... | CONVERT TO CHARACTER SETcharset_name[COLLATEcollation_name] | [DEFAULT] CHARACTER SET [=]charset_name[COLLATE [=]collation_name] | DISCARD TABLESPACE | IMPORT TABLESPACEindex_col_name:col_name[(length)] [ASC | DESC]index_type: USING {BTREE | HASH}table_options:table_option[[,]table_option] ... (seeCREATE TABLEoptions)
ALTER TABLE changes the structure
of a table. For example, you can add or delete columns, create or
destroy indexes, change the type of existing columns, or rename
columns or the table itself. You can also change characteristics
such as the storage engine used for the table or the table
comment.
Following the table name, specify the alterations to be made. If
none are given, ALTER TABLE does
nothing.
The syntax for many of the permissible alterations is similar to
clauses of the CREATE TABLE
statement. See Section 13.1.10, “CREATE TABLE Syntax”, for more
information.
table_options signifies table options
of the kind that can be used in the CREATE
TABLE statement, such as ENGINE,
AUTO_INCREMENT,
AVG_ROW_LENGTH, MAX_ROWS, or
ROW_FORMAT. For a list of all table options and
a description of each, see Section 13.1.10, “CREATE TABLE Syntax”.
However, ALTER TABLE ignores the
DATA DIRECTORY and INDEX
DIRECTORY table options.
Some operations may result in warnings if attempted on a table for
which the storage engine does not support the operation. These
warnings can be displayed with SHOW
WARNINGS. See Section 13.7.5.37, “SHOW WARNINGS Syntax”.
If you use ALTER TABLE to change a
column specification but DESCRIBE
indicates that your
column was not changed, it is possible that MySQL ignored your
modification for one of the reasons described in
Section 13.1.10.4, “Silent Column Specification Changes”.
tbl_name
Some operations may result in warnings if attempted on a table for
which the storage engine does not support the operation. These
warnings can be displayed with SHOW
WARNINGS. See Section 13.7.5.37, “SHOW WARNINGS Syntax”.
For information on troubleshooting ALTER
TABLE, see Section B.5.7.1, “Problems with ALTER TABLE”.
In most cases, ALTER TABLE makes a
temporary copy of the original table. MySQL waits for other
operations that are modifying the table, then proceeds. It
incorporates the alteration into the copy, deletes the original
table, and renames the new one. While ALTER
TABLE is executing, the original table is readable by
other sessions. Updates and writes to the table that begin after
the ALTER TABLE operation begins
are stalled until the new table is ready, then are automatically
redirected to the new table without any failed updates. The
temporary copy of the original table is created in the database
directory of the new table. This can differ from the database
directory of the original table for ALTER
TABLE operations that rename the table to a different
database.
If you use ALTER TABLE
without any
other options, MySQL simply renames any files that correspond to
the table tbl_name RENAME TO
new_tbl_nametbl_name without making a
copy. (You can also use the RENAME
TABLE statement to rename tables. See
Section 13.1.20, “RENAME TABLE Syntax”.) Any privileges granted
specifically for the renamed table are not migrated to the new
name. They must be changed manually.
If you use any option to ALTER
TABLE other than RENAME, MySQL always
creates a temporary table, even if the data wouldn't strictly need
to be copied (such as when you change the name of a column). For
MyISAM tables, you can speed up index
re-creation (the slowest part of the alteration process) by
setting the
myisam_sort_buffer_size system
variable to a high value.
To use ALTER TABLE, you need
ALTER,
CREATE, and
INSERT privileges for the
table. Renaming a table requires
ALTER and
DROP on the old table,
ALTER,
CREATE, and
INSERT on the new table.
IGNORE is a MySQL extension to standard
SQL. It controls how ALTER
TABLE works if there are duplicates on unique keys
in the new table or if warnings occur when strict mode is
enabled. If IGNORE is not specified, the
copy is aborted and rolled back if duplicate-key errors occur.
If IGNORE is specified, only one row is
used of rows with duplicates on a unique key. The other
conflicting rows are deleted. Incorrect values are truncated
to the closest matching acceptable value.
Pending INSERT DELAYED
statements are lost if a table is write locked and
ALTER TABLE is used to modify
the table structure.
table_options signifies table
options of the kind that can be used in the
CREATE TABLE statement, such as
ENGINE, AUTO_INCREMENT,
AVG_ROW_LENGTH,
MAX_ROWS, or ROW_FORMAT.
For a list of all table options and a description of each, see
Section 13.1.10, “CREATE TABLE Syntax”. However,
ALTER TABLE ignores the
DATA DIRECTORY and INDEX
DIRECTORY table options.
For example, to convert a table to be an
InnoDB table, use this statement:
ALTER TABLE t1 ENGINE = InnoDB;
When you specify an ENGINE clause,
ALTER TABLE rebuilds the table.
This is true even if the table already has the specified
storage engine.
The outcome of attempting to change a table's storage engine
is affected by whether the desired storage engine is available
and the setting of the
NO_ENGINE_SUBSTITUTION SQL
mode, as described in Section 5.1.7, “Server SQL Modes”.
As of MySQL 5.0.23, to prevent inadvertent loss of data,
ALTER TABLE cannot be used to
change the storage engine of a table to
MERGE or BLACKHOLE.
To change the value of the AUTO_INCREMENT
counter to be used for new rows, do this:
ALTER TABLE t2 AUTO_INCREMENT = value;
You cannot reset the counter to a value less than or equal to
any that have already been used. For
MyISAM, if the value is less than or equal
to the maximum value currently in the
AUTO_INCREMENT column, the value is reset
to the current maximum plus one. For
InnoDB, you can use ALTER TABLE
... AUTO_INCREMENT =
as of MySQL 5.0.3,
but if the value is less than the current maximum
value in the column, no error occurs and the current sequence
value is not changed.
value
You can issue multiple ADD,
ALTER, DROP, and
CHANGE clauses in a single
ALTER TABLE statement,
separated by commas. This is a MySQL extension to standard
SQL, which permits only one of each clause per
ALTER TABLE statement. For
example, to drop multiple columns in a single statement, do
this:
ALTER TABLE t2 DROP COLUMN c, DROP COLUMN d;
CHANGE ,
col_nameDROP ,
and col_nameDROP INDEX are MySQL extensions to
standard SQL.
The word COLUMN is optional and can be
omitted.
column_definition clauses use the
same syntax for ADD and
CHANGE as for CREATE
TABLE. See Section 13.1.10, “CREATE TABLE Syntax”.
You can rename a column using a CHANGE
clause.
To do so, specify the old and new column names and the
definition that the column currently has. For example, to
rename an old_col_name
new_col_name
column_definitionINTEGER column from
a to b, you can do this:
ALTER TABLE t1 CHANGE a b INTEGER;
To change a column's type but not the name,
CHANGE syntax still requires an old and new
column name, even if they are the same. For example:
ALTER TABLE t1 CHANGE b b BIGINT NOT NULL;
You can also use MODIFY to change a
column's type without renaming it:
ALTER TABLE t1 MODIFY b BIGINT NOT NULL;
MODIFY is an extension to
ALTER TABLE for Oracle
compatibility.
When you use CHANGE or
MODIFY,
column_definition must include the
data type and all attributes that should apply to the new
column, other than index attributes such as PRIMARY
KEY or UNIQUE. Attributes present
in the original definition but not specified for the new
definition are not carried forward. Suppose that a column
col1 is defined as INT UNSIGNED
DEFAULT 1 COMMENT 'my column' and you modify the
column as follows:
ALTER TABLE t1 MODIFY col1 BIGINT;
The resulting column will be defined as
BIGINT, but will not include the attributes
UNSIGNED DEFAULT 1 COMMENT 'my column'. To
retain them, the statement should be:
ALTER TABLE t1 MODIFY col1 BIGINT UNSIGNED DEFAULT 1 COMMENT 'my column';
When you change a data type using CHANGE or
MODIFY, MySQL tries to convert existing
column values to the new type as well as possible.
This conversion may result in alteration of data. For
example, if you shorten a string column, values may be
truncated. To prevent the operation from succeeding if
conversions to the new data type would result in loss of
data, enable strict SQL mode before using
ALTER TABLE (see
Section 5.1.7, “Server SQL Modes”).
To add a column at a specific position within a table row, use
FIRST or AFTER
. The default is
to add the column last. You can also use
col_nameFIRST and AFTER in
CHANGE or MODIFY
operations to reorder columns within a table.
ALTER ... SET DEFAULT or ALTER ...
DROP DEFAULT specify a new default value for a
column or remove the old default value, respectively. If the
old default is removed and the column can be
NULL, the new default is
NULL. If the column cannot be
NULL, MySQL assigns a default value as
described in Section 11.6, “Data Type Default Values”.
DROP INDEX removes an index.
This is a MySQL extension to standard SQL. See
Section 13.1.15, “DROP INDEX Syntax”. If you are unsure of the index
name, use SHOW INDEX FROM
.
tbl_name
If columns are dropped from a table, the columns are also
removed from any index of which they are a part. If all
columns that make up an index are dropped, the index is
dropped as well. If you use CHANGE or
MODIFY to shorten a column for which an
index exists on the column, and the resulting column length is
less than the index length, MySQL shortens the index
automatically.
If a table contains only one column, the column cannot be
dropped. If what you intend is to remove the table, use
DROP TABLE instead.
DROP PRIMARY KEY drops the primary key. If
there is no primary key, an error occurs.
If you add a UNIQUE INDEX or
PRIMARY KEY to a table, MySQL stores it
before any nonunique index to permit detection of duplicate
keys as early as possible.
Some storage engines permit you to specify an index type when
creating an index. The syntax for the
index_type specifier is
USING .
For details about type_nameUSING, see
Section 13.1.8, “CREATE INDEX Syntax”. Before MySQL 5.0.60,
USING can be given only before the index
column list. As of 5.0.60, the preferred position is after the
column list. Support for use of the option before the column
list will be removed in a future MySQL release.
index_option values specify
additional options for an index. USING is
one such option. For details about permissible
index_option values, see
Section 13.1.8, “CREATE INDEX Syntax”.
After an ALTER TABLE statement,
it may be necessary to run ANALYZE
TABLE to update index cardinality information. See
Section 13.7.5.18, “SHOW INDEX Syntax”.
ORDER BY enables you to create the new
table with the rows in a specific order. This option is useful
primarily when you know that you are mostly to query the rows
in a certain order most of the time. By using this option
after major changes to the table, you might be able to get
higher performance. In some cases, it might make sorting
easier for MySQL if the table is in order by the column that
you want to order it by later.
The table does not remain in the specified order after inserts and deletes.
ORDER BY syntax permits one or more column
names to be specified for sorting, each of which optionally
can be followed by ASC or
DESC to indicate ascending or descending
sort order, respectively. The default is ascending order. Only
column names are permitted as sort criteria; arbitrary
expressions are not permitted. This clause should be given
last after any other clauses.
ORDER BY does not make sense for
InnoDB tables because
InnoDB always orders table rows according
to the clustered
index. The same is true for BDB
tables that contain a user-defined PRIMARY
KEY.
If you use ALTER TABLE on a
MyISAM table, all nonunique indexes are
created in a separate batch (as for
REPAIR TABLE). This should make
ALTER TABLE much faster when
you have many indexes.
For MyISAM tables, key updating can be
controlled explicitly. Use ALTER TABLE ... DISABLE
KEYS to tell MySQL to stop updating nonunique
indexes. Then use ALTER TABLE ... ENABLE
KEYS to re-create missing indexes.
MyISAM does this with a special algorithm
that is much faster than inserting keys one by one, so
disabling keys before performing bulk insert operations should
give a considerable speedup. Using ALTER TABLE ...
DISABLE KEYS requires the
INDEX privilege in addition to
the privileges mentioned earlier.
While the nonunique indexes are disabled, they are ignored for
statements such as SELECT and
EXPLAIN that otherwise would
use them.
If ALTER TABLE for an
InnoDB table results in changes to column
values (for example, because a column is truncated),
InnoDB's FOREIGN KEY
constraint checks do not notice possible violations caused by
changing the values.
The FOREIGN KEY and
REFERENCES clauses are supported by the
InnoDB storage engine, which implements
ADD [CONSTRAINT [. See
Section 14.2.3.4, “InnoDB and FOREIGN KEY Constraints”. For other
storage engines, the clauses are parsed but ignored. The
symbol]]
FOREIGN KEY [index_name] (...)
REFERENCES ... (...)CHECK clause is parsed but ignored by all
storage engines. See Section 13.1.10, “CREATE TABLE Syntax”. The
reason for accepting but ignoring syntax clauses is for
compatibility, to make it easier to port code from other SQL
servers, and to run applications that create tables with
references. See Section 1.8.2, “MySQL Differences from Standard SQL”.
For ALTER TABLE, unlike
CREATE TABLE, ADD
FOREIGN KEY ignores
index_name if given and uses an
automatically generated foreign key name. As a workaround,
include the CONSTRAINT clause to specify
the foreign key name:
ADD CONSTRAINT name FOREIGN KEY (....) ...
The inline REFERENCES specifications
where the references are defined as part of the column
specification are silently ignored by
InnoDB. InnoDB only accepts
REFERENCES clauses defined as part of a
separate FOREIGN KEY specification.
InnoDB supports the use of
ALTER TABLE to drop foreign
keys:
ALTER TABLEtbl_nameDROP FOREIGN KEYfk_symbol;
For more information, see Section 14.2.3.4, “InnoDB and FOREIGN KEY Constraints”.
Adding and dropping a foreign key in separate clauses of a
single ALTER TABLE statement
may be problematic in some cases and is therefore unsupported.
Use separate statements for each operation.
For an InnoDB table that is created with
its own tablespace in an .ibd file, that
file can be discarded and imported. To discard the
.ibd file, use this statement:
ALTER TABLE tbl_name DISCARD TABLESPACE;
This deletes the current .ibd file, so be
sure that you have a backup first. Attempting to access the
table while the tablespace file is discarded results in an
error.
To import the backup .ibd file back into
the table, copy it into the database directory, and then issue
this statement:
ALTER TABLE tbl_name IMPORT TABLESPACE;
The tablespace file must have been created on the server into which it is imported later.
To change the table default character set and all character
columns (CHAR,
VARCHAR,
TEXT) to a new character set,
use a statement like this:
ALTER TABLEtbl_nameCONVERT TO CHARACTER SETcharset_name[COLLATEcollation_name];
The statement also changes the collation of all character
columns. If you specify no COLLATE clause
to indicate which collation to use, the statement uses default
collation for the character set. If this collation is
inappropriate for the intended table use (for example, if it
would change from a case-sensitive collation to a
case-insensitive collation), specify a collation explicitly.
For a column that has a data type of
VARCHAR or one of the
TEXT types, CONVERT TO
CHARACTER SET will change the data type as necessary
to ensure that the new column is long enough to store as many
characters as the original column. For example, a
TEXT column has two length
bytes, which store the byte-length of values in the column, up
to a maximum of 65,535. For a latin1
TEXT column, each character
requires a single byte, so the column can store up to 65,535
characters. If the column is converted to
utf8, each character might require up to 3
bytes, for a maximum possible length of 3 × 65,535 =
196,605 bytes. That length will not fit in a
TEXT column's length bytes, so
MySQL will convert the data type to
MEDIUMTEXT, which is the
smallest string type for which the length bytes can record a
value of 196,605. Similarly, a
VARCHAR column might be
converted to MEDIUMTEXT.
To avoid data type changes of the type just described, do not
use CONVERT TO CHARACTER SET. Instead, use
MODIFY to change individual columns. For
example:
ALTER TABLE t MODIFY latin1_text_col TEXT CHARACTER SET utf8;
ALTER TABLE t MODIFY latin1_varchar_col VARCHAR(M) CHARACTER SET utf8;
If you specify CONVERT TO CHARACTER SET
binary, the CHAR,
VARCHAR, and
TEXT columns are converted to
their corresponding binary string types
(BINARY,
VARBINARY,
BLOB). This means that the
columns no longer will have a character set and a subsequent
CONVERT TO operation will not apply to
them.
If charset_name is
DEFAULT, the database character set is
used.
The CONVERT TO operation converts column
values between the character sets. This is
not what you want if you have a column
in one character set (like latin1) but
the stored values actually use some other, incompatible
character set (like utf8). In this case,
you have to do the following for each such column:
ALTER TABLE t1 CHANGE c1 c1 BLOB; ALTER TABLE t1 CHANGE c1 c1 TEXT CHARACTER SET utf8;
The reason this works is that there is no conversion when
you convert to or from BLOB
columns.
To change only the default character set for a table, use this statement:
ALTER TABLEtbl_nameDEFAULT CHARACTER SETcharset_name;
The word DEFAULT is optional. The default
character set is the character set that is used if you do not
specify the character set for columns that you add to a table
later (for example, with ALTER TABLE ... ADD
column).
With the mysql_info() C API
function, you can find out how many rows were copied by
ALTER TABLE, and (when
IGNORE is used) how many rows were deleted due
to duplication of unique key values. See
Section 20.6.7.35, “mysql_info()”.

User Comments
IF you want to change a SET or ENUM column you may
not want to use the ALTER TABLE ... MODIFY
syntax.
It tries to keep the actual string values and not
the integer representation of the values, even
though they are stored as integers.
For example, if you just want to make a change in
spelling of the values in your enum column or your
set column, consider doing it like this:
ALTER TABLE table ADD new_column ...;
UPDATE table SET new_column = old_column + 0;
ALTER TABLE table DROP old_column;
You can use Alter Table to optimise a table without locking out selects (only writes), by altering a column to be the same as it's current definition. This is better than using repair table which obtains a read/write lock.
1 row in set (0.00 sec)E.g.
mysql> describe Temp_Table;
mysql> alter table Temp_Table change column ID ID int unsigned;
This will cause mysql to re-create the table and thus remove any deleted space.
This is useful for 24/7 databases where you don't want to completely lock a table.
If you are just changing a column name on a MyISAM table and want to avoid duplicating the entire table, try the following (no warranty provided but worked for me):
For peace-of-mind -- try this with some dummy data first!
1. Backup the <original_table>.frm file from your master table (and the data if you can, but you're probably reading this because you can't).
2. create table with the identical schema to the one you want to alter (type "show create table <tablename> and just change the name to something). Lets say you called the table "rename_temp1"
3. execute the "alter table <rename_temp1> change <old_column_name> <new_column_name> char(128) not null" [substituting your the old definition -- ensuring you keep column type the same]
3. Ensuring you a have made a copy of your original .frm file -- copy the <rename_temp1>.frm file to <original_table>.frm.
4. voila -- all going well your column should be renamed without a full copy in/out (very useful for 140G tables...)
5. probably best to run a myisamchck on the table before making live again
When you want to drop a UNIQUE KEY in an InnoDb table, have to pay attention not to occure this situation:
Please check that columns used in the UNIQUE KEY are not used as FOREIGN KEY (each of them).
If so, must to drop that Forign keys first.
See Example below please.
UNIQUE KEY `unique` (`id1`, `id2`),
CONSTRAINT `fk_1` FOREIGN KEY (`id1`) REFERENCES `tbl1` (`id`) ON DELETE CASCADE,
CONSTRAINT `fk_2` FOREIGN KEY (`id2`) REFERENCES `tbl2` (`id`) ON DELETE CASCADE
In this situation, you have to drop both FOREIGN KEYs first, in order to can drop the UNIQUE KEY.
If you're trying to convert a whole database to a different character set, and you thought you might have to change the fields one by one, this kind of command is really handy:
ALTER TABLE tablename CONVERT TO CHARACTER SET utf8 COLLATE utf8_general_ci;
However, after using it on a lot of tables I made the grim discovery that for older myisam tables that didn't have any character set, it mangled the length of most varchar fields. Specifically, it divided their length with 3. Bizarrely, it didn't lose the existing data, even though it was longer than the field lengths, but it was a problem with new records and with indexes.
So, if you're going to do a character set converstion, make sure the table already has a character set. That it doesn't might not be immediately obvious, as tools like phpMyAdmin will show the default character set, if the table or the field doesn't have one set.
TO ADD A FOREIGN KEY TO AN EXISTING TABLE (I couldn't see a good example) you can do this:
alter table users add foreign key(favGenre) references products_genre(gid);
Where favgenre is the column of the table that has the foreign key and products_genre(gid) is the table and primary key you are referencing.
Attempting to "ALTER TABLE ... DROP PRIMARY KEY" on a table when an AUTO_INCREMENT column exists in the key generates an error:
ERROR 1075 (42000): Incorrect table definition; there can be only one auto column and it must be defined as a key.
To make this work without erroring, drop and re-add the new primary key in a single statement, e.g.:
ALTER TABLE mytable DROP PRIMARY KEY, ADD PRIMARY KEY(col1,col2);
You can't drop a NOT NULL constraint on a column the way you can a foreign key or an index, or a default. Instead, just use the 'change' or 'modify' syntax and leave off the NOT NULL bit:
alter table table_name modify col_name bigint default null;
Any pre-existing indexes or foreign keys on the column are not affected.
If you are trying to change the case of a table name using the ALTER TABLE syntax and it appears to fail silently,
or if you try to RENAME TABLE something TO soMeThiNg and get a 'table already exists' error,
or if you try to CREATE TABLE MixedCaseTableName and get a table named mixedcasetablename, these are not bugs:
See: Identifier Case Sensitivity
http://dev.mysql.com/doc/refman/5.0/en/identifier-case-sensitivity.html
If your development environment has MySQL5 and you're hosting on MySQL4 you can get 'table not found' errors based on the case of the table names.
As mentioned above, ALTER TABLE is going to make a temporary copy of the whole table data (.MYD) in the same directory as the original table and not in the temporary directories given to MySQL.
In some cases a third copy of the table (.TMD) is made. This means you must have up to three copies of free space in that directory. Unfortunately MySQL does not break the files into pieces if it runs out of space.
As a table grows larger this process becomes more expensive. Therefore, keys and indices must be added as early as possible to large tables in spite of the update cost that comes with each insert.
For moving a table from one database to another just do:
use db_old;
alter table tab_name rename db_new.tab_name;
There seem to any number of convoluted methods (not to mention some finger wagging by purists questioning the practice, even here) for altering the sequence of fields in a MySQL table but ALTER does the job as prescribed. It isn't completely self-evident from the description above so here's what worked for me:
ALTER TABLE tablex CHANGE colx colx colxtype AFTER coly.
That is, you're not changing the name of the column but still need to specify 'oldname newname' as 'oldname oldname'
Converting_Database_Character_Sets
http://codex.wordpress.org/Converting_Database_Character_Sets
If you want to change the table's engine for all tables, you can use this code to generate your sql script.
From MyISAM engine to InnoDB engine: set db_name and db_username then copy and paste the follow lines on a Linux/MacOSX shell.
DB_NAME="db_name";
mysql --user=db_username -p --execute="USE information_schema; SELECT CONCAT(\"ALTER TABLE \`\", TABLE_SCHEMA,\"\`.\`\", TABLE_NAME, \"\` TYPE = InnoDB;\") as MySQLCMD from TABLES where TABLE_SCHEMA = \""${DB_NAME}"\";" > ${DB_NAME}-temp.sql;
#delete first line
sed '/MySQLCMD/d' ${DB_NAME}-temp.sql > ${DB_NAME}-innodb.sql;
mysql --user=db_username -p < ${DB_NAME}-innodb.sql;
rm ${DB_NAME}-temp.sql;
rm ${DB_NAME}-innodb.sql;
You can customize the code above for your OS.
I used code from here:
http://forums.mysql.com/read.php?20,244395,244421#msg-244421
Found some good alter table here:
http://www.examplenow.com/mysql/alter
--John
It is okay to add two or more columns in the same query where the before and after clauses refer to newly created columns:
ALTER TABLE mytable ADD COLUMN dummy1 VARCHAR(40) AFTER id ADD COLUMN dummy2 VARCHAR(12) AFTER dummy1;
If you use "ALTER TABLE mytable AUTO_INCREMENT = N" the MySQL server will create a new table, copy all the data from the old table to the new, delete the old and then rename the new one even though there is no structural change to the table. The server response will show that all the rows have been "affected", like this:
mysql> alter table mytable auto_increment=1000000;
Query OK, 512691 rows affected (1 min 4.55 sec)
Records: 512691 Duplicates: 0 Warnings: 0
There are potential issues that may arise from the table copy, especially if you didn't expect it! I.e. is there a sufficient amount of free disk space for the second copy of the data, etc., etc..
The bottom line for me is to go back to the "old fashioned way" - just insert a dummy row and explicitly set the AUTO_INCREMENT column to N - 1, then immediately delete the dummy row. The next row that is inserted will start at N and go from there.
none of the alter code sql queries were working for me in phpmyadmin
however after digging much, finally found something that may help you all.
use this query code:
ALTER TABLE table_name MODIFY column_to_move column_type AFTER column_to_reference
have explained it with example here:
http://nabtron.com/alter-sequence-columns-field-database-table-mysql-phpmyadmin/1914/
If you need copy big MYISAM tables, just create a new table with same structure (SHOW CREATE TABLE table_to_copy; CREATE TABLE new_table %old table structure%), then copy old table's .frm, .MYD and .MYI files, rename copied files from old_name.* to new_name.*, then run ANALYZE TABLE new_name. No need to restart MySql.
If you want to ALTER a table and set the default value to CURRENT_TIMESTAMP for a timestamp column, the listed syntax of "ALTER TABLE foo ALTER COLUMN ts SET DEFAULT CURRENT_TIMESTAMP" will NOT work.
Instead, the syntax below will work. You also need to put the column name twice, I don't know why, it just works.
"ALTER TABLE tablename CHANGE columnname columnname TIMESTAMP DEFAULT CURRENT_TIMESTAMP;"
When adding a new column to a table, and making it a foreign key, if you get
ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails
please check :
1, The new column must be an index column,
2, All value in the new column must be valid foreign keys.
Here are correct steps:
(Suppose you have author in volumes table, but want to add it to books table.)
ALTER TABLE books ADD COLUMN `author` int(10) unsigned NOT NULL ;
ALTER TABLE books ADD INDEX (author) ;
UPDATE books SET author = ( SELECT author FROM volumes WHERE volumes.id = books.volume_id ) ;
ALTER TABLE books ADD FOREIGN KEY (author) REFERENCES `users` (`id`) ;
It is not possible to change a column name on an InnoDB table if the column participates in a foreign key without first dropping the foreign key. It does not matter if the column is used to reference another table or if it is referenced by another table in the foreign key.
Stored procedure to add a column (sorry about the lack of indentation, the comment box seems to strip leading spaces.)
delimiter //
drop procedure if exists AddTableColumn //
create procedure AddTableColumn
( in schemaName varchar(128) -- If null use name of current schema;
, in tableName varchar(128) -- If null an exception will be thrown.
, in columnName varchar(128) -- If null an exception will be thrown.
, in columnDefinition varchar(1024) -- E.g. 'int not null default 1' (Can include comment here if columnComment is null.)
, in columnComment varchar(1024) -- E.g. 'comment about column.' Can be null. (If null then the comment can be included in columnDefinition.)
, in ifPresent enum('leaveUnchanged', 'dropAndReplace', 'modifyExisting') -- null=leaveUnchanged.
, out outcome tinyint(1) -- 0=unchanged, 1=replaced, 2=modified, 4=added.
)
begin
declare doDrop tinyint(1) default null;
declare doAdd tinyint(1) default null;
declare doModify tinyint(1) default null;
declare tmpSql varchar(4096) default '';
set schemaName = coalesce(schemaName, schema());
set ifPresent = coalesce(ifPresent, 'leaveUnchanged');
-- select schemaName, ifPresent;
if exists
(select *
from `information_schema`.`COLUMNS`
where `COLUMN_NAME` = columnName
and `TABLE_NAME` = tableName
and `TABLE_SCHEMA` = schemaName
)
then
-- select 'exists';
if (ifPresent = 'leaveUnchanged')
then
set doDrop = 0;
set doAdd = 0;
set doModify = 0;
set outcome = 0;
elseif (ifPresent = 'dropAndReplace')
then
set doDrop = 1;
set doAdd = 1;
set doModify = 0;
set outcome = 1;
elseif (ifPresent = 'modifyExisting')
then
set doDrop = 0;
set doAdd = 0;
set doModify = 1;
set outcome = 2;
end if;
else
-- select 'not-exists';
set doDrop = 0;
set doAdd = 1;
set doModify = 0;
set outcome = 4;
end if;
-- select doDrop, doAdd, doModify, outcome;
if (doDrop = 1)
then
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` drop column `', columnName, '` ');
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;
if (doAdd = 1)
then
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` add column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
then
set tmpSql = concat(tmpSql, ' comment "', columnComment, '"');
end if;
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;
if (doModify = 1)
then
set tmpSql = concat( 'alter table `', schemaName, '`.`', tableName, '` modify column `', columnName, '` ', columnDefinition);
if (columnComment is not null)
then
set tmpSql = concat(tmpSql, ' comment "', columnComment, '"');
end if;
set @sql = tmpSql;
prepare tmp_stmt from @sql;
execute tmp_stmt;
deallocate prepare tmp_stmt;
end if;
end; //
CREATE PROCEDURE `clone_table`(IN tablex TEXT)
BEGIN
DECLARE sqls,tablexs,cols TEXT;
DECLARE done INT DEFAULT 0;
DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done=1;
SET tablexs = CONCAT(tablex,'_tmp');
SET @sql=CONCAT('ALTER TABLE `',tablex,'` RENAME TO `',tablexs,'`');
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
DEALLOCATE PREPARE stmt1;
SET @sql=CONCAT('CREATE TABLE ',tablex,' LIKE ',tablexs);
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
DEALLOCATE PREPARE stmt1;
SELECT column_name INTO cols
FROM `information_schema`.`COLUMNS`
WHERE table_name=tablexs
AND table_schema=DATABASE()
AND column_key='pri' AND extra='auto_increment';
IF NOT done THEN
SELECT `auto_increment` INTO @id
FROM `information_schema`.`TABLES`
WHERE table_name=tablexs
AND table_schema=DATABASE();
SET @sql=CONCAT('ALTER TABLE `',tablex,'` AUTO_INCREMENT=',@id);
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
DEALLOCATE PREPARE stmt1;
END IF;
END $$
AND
CREATE PROCEDURE `clone_table_sync`(IN table_namex VARCHAR(100), IN idx INT)
BEGIN
DECLARE done, ids INT DEFAULT 0;
DECLARE table_namexs TEXT;
DECLARE CONTINUE HANDLER FOR SQLSTATE '02000' SET done=1;
SET table_namexs = CONCAT(table_namex,'_tmp');
SELECT `auto_increment` INTO ids
FROM `information_schema`.`TABLES`
WHERE table_name=table_namexs
AND table_schema=DATABASE();
WHILE ids>idx DO
SET @sql=CONCAT('INSERT IGNORE INTO `',table_namex,'` SELECT * FROM `',table_namexs,
'` WHERE i_id>',idx,' AND i_id<=',(idx+5000));
PREPARE stmt1 FROM @sql;
EXECUTE stmt1;
DEALLOCATE PREPARE stmt1;
-- SELECT SLEEP(1) INTO @tmp2;
SET idx=idx+5000;
END WHILE;
END $$
An addition to John Walker's example above for reordering the columns in a table.
ALTER TABLE tablex CHANGE colx colx colxtype AFTER coly
Not only do you need to specify 'oldname newname' as 'oldname oldname', you also need to respecify the type of 'oldname' as 'colxtype' (or change it of course) for the statement to work.
ALTER TABLE sales.order ADD UNIQUE(order_ref);
This command will update 'sales' databases 'order' tables 'order_ref' column to become uniquely indexed. If the column already have some duplicate data, an error message will be prompted.
Note that if you include 'UNIQUE' as part of the column definition in an ALTER TABLE MODIFY COLUMN ... statement for a column which was original defined as UNIQUE, MySQL will create a second UNIQUE index. What you need to do if you don't want that second index (any why would you? as it does nothing but slow things down), and you're dealing with scripted changes which you have to give to a separate DBA team who won't accept any instructions which involve manual work (so they won't examine the results of the ALTER TABLE statement to find out the name of the extra index which needs to be dropped), on a server over which you don't have administrative privileges, is to leave out the UNIQUE keyword from the column definition, knowing that MySQL will leave the UNIQUE constraint in place. It's as if MySQL doesn't consider 'UNIQUE' as part of the column definition (even though the syntax rules include it as part of column_definition).
If you are just changing a column name on a MyISAM table and want to avoid duplicating the entire table, try the following (no warranty provided but worked for me for my website http://techleaks.us/ . I wasted my 4 days looking and searching all around this..):
For peace-of-mind -- try this with some dummy data first!
1. Backup the <original_table>.frm file from your master table (and the data if you can, but you're probably reading this because you can't).
2. create table with the identical schema to the one you want to alter (type "show create table <tablename> and just change the name to something). Lets say you called the table "rename_temp1"
3. execute the "alter table <rename_temp1> change <old_column_name> <new_column_name> char(128) not null" [substituting your the old definition -- ensuring you keep column type the same]
3. Ensuring you a have made a copy of your original .frm file -- copy the <rename_temp1>.frm file to <original_table>.frm.
4. voila -- all going well your column should be renamed without a full copy in/out (very useful for 140G tables...)
5. probably best to run a myisamchck on the table before making live again