[postgres@redhat6 pg_root]$ psql francs francs psql (9.2beta1) Type"help"for help. francs=> create table test_alter (id integer,name varchar(32),flag numeric(1,0)); CREATE TABLE francs=> insert into test_alter select generate_series(1,2000000),'francs',0; INSERT 02000000 francs=> /d test_alter Table"francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(32) | flag | numeric(1,0) francs=> select * from test_alter limit 1; id | name | flag ----+--------+------ 1 | francs | 0 (1 row)
varchar 字段扩长
1 2 3 4 5 6 7 8 9 10 11
francs=> alter table test_alter alter name type character varying(64); ALTER TABLE Time: 1161.613 ms francs=> /d test_alter Table "francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(64) | flag | numeric(1,0) |
skytf => /d test_alter Table"francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(32) | flag | numeric(1,0) skytf=> alter table test_alter alter name type character varying(64); ALTER TABLE Time: 7844.453 ms
skytf=> /d test_alter Table"skytf.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(64) | flag | numeric(1,0) |
francs=>/d test_alter Table "francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(64) | flag | numeric(1,0) | francs=> alter table test_alter alter column flag type numeric (2,0); ALTER TABLE Time: 79.782 ms
francs=> /d test_alter Table "francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | notnull name | character varying(64) | flag | numeric(2,0) |
PostgreSQL9.1
1 2 3 4 5 6 7 8 9 10
skytf=> /d test_alter Table "skytf.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | name | character varying(64) | flag | numeric(1,0) | skytf=> alter table test_alter alter column flag type numeric (2,0); ALTER TABLE Time: 13236.818 ms
francs=> /d test_alter Table "francs.test_alter" Column | Type | Modifiers --------+-----------------------+----------- id | integer | notnull name | character varying(64) | flag | numeric(2,0) | Indexes: "idx_test_alter_name" btree (name) francs=> alter table test_alter alter column name type text; ALTER TABLE Time: 1405.116 ms francs=> /d test_alter Table "francs.test_alter" Column | Type | Modifiers --------+--------------+----------- id | integer | notnull name | text | flag | numeric(2,0) | Indexes: "idx_test_alter_name" btree (name)
PostgreSQL9.1
1 2 3 4 5 6 7 8 9 10 11 12 13
skytf=> alter table test_alter alter column name type text; ALTER TABLE Time: 13487.664 ms skytf=> /d test_alter Table "skytf.test_alter" Column | Type | Modifiers --------+--------------+----------- id | integer | name | text | flag | numeric(2,0) | Indexes: "idx_test_alter_name" btree (name)
备注:当 varchar 字段扩长到 text 字段时, PostgreSQL9.2 版本没重写表,PostgreSQL9.1 版本需要重写。
不需要重写表的场景
在 PostgreSQL9.2 中不需要重写表的“ALTER TABLE “ 场景:
varchar(x) to varchar(y) when y>=x. It works too if going from varchar(x) to varchar or text (no size limitation)
numeric(x,z) to numeric(y,z) when y>=x, or to numeric without specifier
varbit(x) to varbit(y) when y>=x, or to varbit without specifier
timestamp(x) to timestamp(y) when y>=x or timestamp without specifier
timestamptz(x) to timestamptz(y) when y>=x or timestamptz without specifier
interval(x) to interval(y) when y>=x or interval without specifier