mirror of
https://github.com/postgres/postgres.git
synced 2025-04-24 10:47:04 +03:00
there was a race condition between the "alter_table" and "rules" regression tests. Depending on scheduling, sometimes an ALTER TABLE command would operate on a relation created by the "rules" tests, leading to unexpected results. Neil Conway
734 lines
23 KiB
SQL
734 lines
23 KiB
SQL
--
|
|
-- ALTER_TABLE
|
|
-- add attribute
|
|
--
|
|
|
|
CREATE TABLE tmp (initial int4);
|
|
|
|
ALTER TABLE tmp ADD COLUMN a int4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN b name;
|
|
|
|
ALTER TABLE tmp ADD COLUMN c text;
|
|
|
|
ALTER TABLE tmp ADD COLUMN d float8;
|
|
|
|
ALTER TABLE tmp ADD COLUMN e float4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN f int2;
|
|
|
|
ALTER TABLE tmp ADD COLUMN g polygon;
|
|
|
|
ALTER TABLE tmp ADD COLUMN h abstime;
|
|
|
|
ALTER TABLE tmp ADD COLUMN i char;
|
|
|
|
ALTER TABLE tmp ADD COLUMN j abstime[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN k int4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN l tid;
|
|
|
|
ALTER TABLE tmp ADD COLUMN m xid;
|
|
|
|
ALTER TABLE tmp ADD COLUMN n oidvector;
|
|
|
|
--ALTER TABLE tmp ADD COLUMN o lock;
|
|
ALTER TABLE tmp ADD COLUMN p smgr;
|
|
|
|
ALTER TABLE tmp ADD COLUMN q point;
|
|
|
|
ALTER TABLE tmp ADD COLUMN r lseg;
|
|
|
|
ALTER TABLE tmp ADD COLUMN s path;
|
|
|
|
ALTER TABLE tmp ADD COLUMN t box;
|
|
|
|
ALTER TABLE tmp ADD COLUMN u tinterval;
|
|
|
|
ALTER TABLE tmp ADD COLUMN v timestamp;
|
|
|
|
ALTER TABLE tmp ADD COLUMN w interval;
|
|
|
|
ALTER TABLE tmp ADD COLUMN x float8[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN y float4[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN z int2[];
|
|
|
|
INSERT INTO tmp (a, b, c, d, e, f, g, h, i, j, k, l, m, n, p, q, r, s, t, u,
|
|
v, w, x, y, z)
|
|
VALUES (4, 'name', 'text', 4.1, 4.1, 2, '(4.1,4.1,3.1,3.1)',
|
|
'Mon May 1 00:30:30 1995', 'c', '{Mon May 1 00:30:30 1995, Monday Aug 24 14:43:07 1992, epoch}',
|
|
314159, '(1,1)', '512',
|
|
'1 2 3 4 5 6 7 8', 'magnetic disk', '(1.1,1.1)', '(4.1,4.1,3.1,3.1)',
|
|
'(0,2,4.1,4.1,3.1,3.1)', '(4.1,4.1,3.1,3.1)', '["epoch" "infinity"]',
|
|
'epoch', '01:00:10', '{1.0,2.0,3.0,4.0}', '{1.0,2.0,3.0,4.0}', '{1,2,3,4}');
|
|
|
|
SELECT * FROM tmp;
|
|
|
|
DROP TABLE tmp;
|
|
|
|
-- the wolf bug - schema mods caused inconsistent row descriptors
|
|
CREATE TABLE tmp (
|
|
initial int4
|
|
);
|
|
|
|
ALTER TABLE tmp ADD COLUMN a int4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN b name;
|
|
|
|
ALTER TABLE tmp ADD COLUMN c text;
|
|
|
|
ALTER TABLE tmp ADD COLUMN d float8;
|
|
|
|
ALTER TABLE tmp ADD COLUMN e float4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN f int2;
|
|
|
|
ALTER TABLE tmp ADD COLUMN g polygon;
|
|
|
|
ALTER TABLE tmp ADD COLUMN h abstime;
|
|
|
|
ALTER TABLE tmp ADD COLUMN i char;
|
|
|
|
ALTER TABLE tmp ADD COLUMN j abstime[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN k int4;
|
|
|
|
ALTER TABLE tmp ADD COLUMN l tid;
|
|
|
|
ALTER TABLE tmp ADD COLUMN m xid;
|
|
|
|
ALTER TABLE tmp ADD COLUMN n oidvector;
|
|
|
|
--ALTER TABLE tmp ADD COLUMN o lock;
|
|
ALTER TABLE tmp ADD COLUMN p smgr;
|
|
|
|
ALTER TABLE tmp ADD COLUMN q point;
|
|
|
|
ALTER TABLE tmp ADD COLUMN r lseg;
|
|
|
|
ALTER TABLE tmp ADD COLUMN s path;
|
|
|
|
ALTER TABLE tmp ADD COLUMN t box;
|
|
|
|
ALTER TABLE tmp ADD COLUMN u tinterval;
|
|
|
|
ALTER TABLE tmp ADD COLUMN v timestamp;
|
|
|
|
ALTER TABLE tmp ADD COLUMN w interval;
|
|
|
|
ALTER TABLE tmp ADD COLUMN x float8[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN y float4[];
|
|
|
|
ALTER TABLE tmp ADD COLUMN z int2[];
|
|
|
|
INSERT INTO tmp (a, b, c, d, e, f, g, h, i, j, k, l, m, n, p, q, r, s, t, u,
|
|
v, w, x, y, z)
|
|
VALUES (4, 'name', 'text', 4.1, 4.1, 2, '(4.1,4.1,3.1,3.1)',
|
|
'Mon May 1 00:30:30 1995', 'c', '{Mon May 1 00:30:30 1995, Monday Aug 24 14:43:07 1992, epoch}',
|
|
314159, '(1,1)', '512',
|
|
'1 2 3 4 5 6 7 8', 'magnetic disk', '(1.1,1.1)', '(4.1,4.1,3.1,3.1)',
|
|
'(0,2,4.1,4.1,3.1,3.1)', '(4.1,4.1,3.1,3.1)', '["epoch" "infinity"]',
|
|
'epoch', '01:00:10', '{1.0,2.0,3.0,4.0}', '{1.0,2.0,3.0,4.0}', '{1,2,3,4}');
|
|
|
|
SELECT * FROM tmp;
|
|
|
|
DROP TABLE tmp;
|
|
|
|
|
|
--
|
|
-- rename -
|
|
-- should preserve indices, which we can check by seeing if a SELECT
|
|
-- chooses an indexscan; however, in the absence of vacuum statistics
|
|
-- it might not. Therefore, vacuum first.
|
|
--
|
|
VACUUM ANALYZE tenk1;
|
|
|
|
ALTER TABLE tenk1 RENAME TO ten_k;
|
|
|
|
-- 20 values, sorted
|
|
SELECT unique1 FROM ten_k WHERE unique1 < 20;
|
|
|
|
-- 20 values, sorted
|
|
SELECT unique2 FROM ten_k WHERE unique2 < 20;
|
|
|
|
-- 100 values, sorted
|
|
SELECT hundred FROM ten_k WHERE hundred = 50;
|
|
|
|
ALTER TABLE ten_k RENAME TO tenk1;
|
|
|
|
-- 5 values, sorted
|
|
SELECT unique1 FROM tenk1 WHERE unique1 < 5;
|
|
|
|
-- ALTER TABLE ... RENAME on non-table relations
|
|
-- renaming indexes (FIXME: this should probably test the index's functionality)
|
|
ALTER TABLE onek_unique1 RENAME TO tmp_onek_unique1;
|
|
ALTER TABLE tmp_onek_unique1 RENAME TO onek_unique1;
|
|
-- renaming views
|
|
CREATE VIEW tmp_view (unique1) AS SELECT unique1 FROM tenk1;
|
|
ALTER TABLE tmp_view RENAME TO tmp_view_new;
|
|
-- 5 values, sorted
|
|
SELECT unique1 FROM tenk1 WHERE unique1 < 5;
|
|
DROP VIEW tmp_view_new;
|
|
-- renaming sequences
|
|
CREATE SEQUENCE foo_seq;
|
|
ALTER TABLE foo_seq RENAME TO foo_seq_new;
|
|
SELECT * FROM foo_seq_new;
|
|
DROP SEQUENCE foo_seq_new;
|
|
-- toast-like relation name
|
|
alter table stud_emp rename to pg_toast_stud_emp;
|
|
alter table pg_toast_stud_emp rename to stud_emp;
|
|
|
|
-- FOREIGN KEY CONSTRAINT adding TEST
|
|
|
|
CREATE TABLE tmp2 (a int primary key);
|
|
|
|
CREATE TABLE tmp3 (a int, b int);
|
|
|
|
CREATE TABLE tmp4 (a int, b int, unique(a,b));
|
|
|
|
CREATE TABLE tmp5 (a int, b int);
|
|
|
|
-- Insert rows into tmp2 (pktable)
|
|
INSERT INTO tmp2 values (1);
|
|
INSERT INTO tmp2 values (2);
|
|
INSERT INTO tmp2 values (3);
|
|
INSERT INTO tmp2 values (4);
|
|
|
|
-- Insert rows into tmp3
|
|
INSERT INTO tmp3 values (1,10);
|
|
INSERT INTO tmp3 values (1,20);
|
|
INSERT INTO tmp3 values (5,50);
|
|
|
|
-- Try (and fail) to add constraint due to invalid source columns
|
|
ALTER TABLE tmp3 add constraint tmpconstr foreign key(c) references tmp2 match full;
|
|
|
|
-- Try (and fail) to add constraint due to invalide destination columns explicitly given
|
|
ALTER TABLE tmp3 add constraint tmpconstr foreign key(a) references tmp2(b) match full;
|
|
|
|
-- Try (and fail) to add constraint due to invalid data
|
|
ALTER TABLE tmp3 add constraint tmpconstr foreign key (a) references tmp2 match full;
|
|
|
|
-- Delete failing row
|
|
DELETE FROM tmp3 where a=5;
|
|
|
|
-- Try (and succeed)
|
|
ALTER TABLE tmp3 add constraint tmpconstr foreign key (a) references tmp2 match full;
|
|
|
|
-- Try (and fail) to create constraint from tmp5(a) to tmp4(a) - unique constraint on
|
|
-- tmp4 is a,b
|
|
|
|
ALTER TABLE tmp5 add constraint tmpconstr foreign key(a) references tmp4(a) match full;
|
|
|
|
DROP TABLE tmp5;
|
|
|
|
DROP TABLE tmp4;
|
|
|
|
DROP TABLE tmp3;
|
|
|
|
DROP TABLE tmp2;
|
|
|
|
-- Foreign key adding test with mixed types
|
|
|
|
-- Note: these tables are TEMP to avoid name conflicts when this test
|
|
-- is run in parallel with foreign_key.sql.
|
|
|
|
CREATE TEMP TABLE PKTABLE (ptest1 int PRIMARY KEY);
|
|
CREATE TEMP TABLE FKTABLE (ftest1 inet);
|
|
-- This next should fail, because inet=int does not exist
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable;
|
|
-- This should also fail for the same reason, but here we
|
|
-- give the column name
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1);
|
|
-- This should succeed, even though they are different types
|
|
-- because varchar=int does exist
|
|
DROP TABLE FKTABLE;
|
|
CREATE TEMP TABLE FKTABLE (ftest1 varchar);
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable;
|
|
-- As should this
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1) references pktable(ptest1);
|
|
DROP TABLE pktable cascade;
|
|
DROP TABLE fktable;
|
|
|
|
CREATE TEMP TABLE PKTABLE (ptest1 int, ptest2 inet,
|
|
PRIMARY KEY(ptest1, ptest2));
|
|
-- This should fail, because we just chose really odd types
|
|
CREATE TEMP TABLE FKTABLE (ftest1 cidr, ftest2 timestamp);
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2) references pktable;
|
|
DROP TABLE FKTABLE;
|
|
-- Again, so should this...
|
|
CREATE TEMP TABLE FKTABLE (ftest1 cidr, ftest2 timestamp);
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2)
|
|
references pktable(ptest1, ptest2);
|
|
DROP TABLE FKTABLE;
|
|
-- This fails because we mixed up the column ordering
|
|
CREATE TEMP TABLE FKTABLE (ftest1 int, ftest2 inet);
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest1, ftest2)
|
|
references pktable(ptest2, ptest1);
|
|
-- As does this...
|
|
ALTER TABLE FKTABLE ADD FOREIGN KEY(ftest2, ftest1)
|
|
references pktable(ptest1, ptest2);
|
|
|
|
-- temp tables should go away by themselves, need not drop them.
|
|
|
|
-- test check constraint adding
|
|
|
|
create table atacc1 ( test int );
|
|
-- add a check constraint
|
|
alter table atacc1 add constraint atacc_test1 check (test>3);
|
|
-- should fail
|
|
insert into atacc1 (test) values (2);
|
|
-- should succeed
|
|
insert into atacc1 (test) values (4);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the check fails when added
|
|
create table atacc1 ( test int );
|
|
-- insert a soon to be failing row
|
|
insert into atacc1 (test) values (2);
|
|
-- add a check constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 check (test>3);
|
|
insert into atacc1 (test) values (4);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the check fails because the column doesn't exist
|
|
create table atacc1 ( test int );
|
|
-- add a check constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 check (test1>3);
|
|
drop table atacc1;
|
|
|
|
-- something a little more complicated
|
|
create table atacc1 ( test int, test2 int, test3 int);
|
|
-- add a check constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 check (test+test2<test3*4);
|
|
-- should fail
|
|
insert into atacc1 (test,test2,test3) values (4,4,2);
|
|
-- should succeed
|
|
insert into atacc1 (test,test2,test3) values (4,4,5);
|
|
drop table atacc1;
|
|
|
|
-- lets do some naming tests
|
|
create table atacc1 (test int check (test>3), test2 int);
|
|
alter table atacc1 add check (test2>test);
|
|
-- should fail for $2
|
|
insert into atacc1 (test2, test) values (3, 4);
|
|
drop table atacc1;
|
|
|
|
-- inheritance related tests
|
|
create table atacc1 (test int);
|
|
create table atacc2 (test2 int);
|
|
create table atacc3 (test3 int) inherits (atacc1, atacc2);
|
|
alter table atacc2 add constraint foo check (test2>0);
|
|
-- fail and then succeed on atacc2
|
|
insert into atacc2 (test2) values (-3);
|
|
insert into atacc2 (test2) values (3);
|
|
-- fail and then succeed on atacc3
|
|
insert into atacc3 (test2) values (-3);
|
|
insert into atacc3 (test2) values (3);
|
|
drop table atacc3;
|
|
drop table atacc2;
|
|
drop table atacc1;
|
|
|
|
-- let's try only to add only to the parent
|
|
|
|
create table atacc1 (test int);
|
|
create table atacc2 (test2 int);
|
|
create table atacc3 (test3 int) inherits (atacc1, atacc2);
|
|
alter table only atacc2 add constraint foo check (test2>0);
|
|
-- fail and then succeed on atacc2
|
|
insert into atacc2 (test2) values (-3);
|
|
insert into atacc2 (test2) values (3);
|
|
-- both succeed on atacc3
|
|
insert into atacc3 (test2) values (-3);
|
|
insert into atacc3 (test2) values (3);
|
|
drop table atacc3;
|
|
drop table atacc2;
|
|
drop table atacc1;
|
|
|
|
-- test unique constraint adding
|
|
|
|
create table atacc1 ( test int );
|
|
-- add a unique constraint
|
|
alter table atacc1 add constraint atacc_test1 unique (test);
|
|
-- insert first value
|
|
insert into atacc1 (test) values (2);
|
|
-- should fail
|
|
insert into atacc1 (test) values (2);
|
|
-- should succeed
|
|
insert into atacc1 (test) values (4);
|
|
-- try adding a unique oid constraint
|
|
alter table atacc1 add constraint atacc_oid1 unique(oid);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the unique constraint fails when added
|
|
create table atacc1 ( test int );
|
|
-- insert soon to be failing rows
|
|
insert into atacc1 (test) values (2);
|
|
insert into atacc1 (test) values (2);
|
|
-- add a unique constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 unique (test);
|
|
insert into atacc1 (test) values (3);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the unique constraint fails
|
|
-- because the column doesn't exist
|
|
create table atacc1 ( test int );
|
|
-- add a unique constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 unique (test1);
|
|
drop table atacc1;
|
|
|
|
-- something a little more complicated
|
|
create table atacc1 ( test int, test2 int);
|
|
-- add a unique constraint
|
|
alter table atacc1 add constraint atacc_test1 unique (test, test2);
|
|
-- insert initial value
|
|
insert into atacc1 (test,test2) values (4,4);
|
|
-- should fail
|
|
insert into atacc1 (test,test2) values (4,4);
|
|
-- should all succeed
|
|
insert into atacc1 (test,test2) values (4,5);
|
|
insert into atacc1 (test,test2) values (5,4);
|
|
insert into atacc1 (test,test2) values (5,5);
|
|
drop table atacc1;
|
|
|
|
-- lets do some naming tests
|
|
create table atacc1 (test int, test2 int, unique(test));
|
|
alter table atacc1 add unique (test2);
|
|
-- should fail for @@ second one @@
|
|
insert into atacc1 (test2, test) values (3, 3);
|
|
insert into atacc1 (test2, test) values (2, 3);
|
|
drop table atacc1;
|
|
|
|
-- test primary key constraint adding
|
|
|
|
create table atacc1 ( test int );
|
|
-- add a primary key constraint
|
|
alter table atacc1 add constraint atacc_test1 primary key (test);
|
|
-- insert first value
|
|
insert into atacc1 (test) values (2);
|
|
-- should fail
|
|
insert into atacc1 (test) values (2);
|
|
-- should succeed
|
|
insert into atacc1 (test) values (4);
|
|
-- inserting NULL should fail
|
|
insert into atacc1 (test) values(NULL);
|
|
-- try adding a primary key oid constraint
|
|
alter table atacc1 add constraint atacc_oid1 primary key(oid);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the primary key constraint fails when added
|
|
create table atacc1 ( test int );
|
|
-- insert soon to be failing rows
|
|
insert into atacc1 (test) values (2);
|
|
insert into atacc1 (test) values (2);
|
|
-- add a primary key (fails)
|
|
alter table atacc1 add constraint atacc_test1 primary key (test);
|
|
insert into atacc1 (test) values (3);
|
|
drop table atacc1;
|
|
|
|
-- let's do another one where the primary key constraint fails when added
|
|
create table atacc1 ( test int );
|
|
-- insert soon to be failing row
|
|
insert into atacc1 (test) values (NULL);
|
|
-- add a primary key (fails)
|
|
alter table atacc1 add constraint atacc_test1 primary key (test);
|
|
insert into atacc1 (test) values (3);
|
|
drop table atacc1;
|
|
|
|
-- let's do one where the primary key constraint fails
|
|
-- because the column doesn't exist
|
|
create table atacc1 ( test int );
|
|
-- add a primary key constraint (fails)
|
|
alter table atacc1 add constraint atacc_test1 primary key (test1);
|
|
drop table atacc1;
|
|
|
|
-- something a little more complicated
|
|
create table atacc1 ( test int, test2 int);
|
|
-- add a primary key constraint
|
|
alter table atacc1 add constraint atacc_test1 primary key (test, test2);
|
|
-- try adding a second primary key - should fail
|
|
alter table atacc1 add constraint atacc_test2 primary key (test);
|
|
-- insert initial value
|
|
insert into atacc1 (test,test2) values (4,4);
|
|
-- should fail
|
|
insert into atacc1 (test,test2) values (4,4);
|
|
insert into atacc1 (test,test2) values (NULL,3);
|
|
insert into atacc1 (test,test2) values (3, NULL);
|
|
insert into atacc1 (test,test2) values (NULL,NULL);
|
|
-- should all succeed
|
|
insert into atacc1 (test,test2) values (4,5);
|
|
insert into atacc1 (test,test2) values (5,4);
|
|
insert into atacc1 (test,test2) values (5,5);
|
|
drop table atacc1;
|
|
|
|
-- lets do some naming tests
|
|
create table atacc1 (test int, test2 int, primary key(test));
|
|
-- only first should succeed
|
|
insert into atacc1 (test2, test) values (3, 3);
|
|
insert into atacc1 (test2, test) values (2, 3);
|
|
insert into atacc1 (test2, test) values (1, NULL);
|
|
drop table atacc1;
|
|
|
|
-- alter table / alter column [set/drop] not null tests
|
|
-- try altering system catalogs, should fail
|
|
alter table pg_class alter column relname drop not null;
|
|
alter table pg_class alter relname set not null;
|
|
|
|
-- try altering non-existent table, should fail
|
|
alter table non_existent alter column bar set not null;
|
|
alter table non_existent alter column bar drop not null;
|
|
|
|
-- test setting columns to null and not null and vice versa
|
|
-- test checking for null values and primary key
|
|
create table atacc1 (test int not null);
|
|
alter table atacc1 add constraint "atacc1_pkey" primary key (test);
|
|
alter table atacc1 alter column test drop not null;
|
|
alter table atacc1 drop constraint "atacc1_pkey";
|
|
alter table atacc1 alter column test drop not null;
|
|
insert into atacc1 values (null);
|
|
alter table atacc1 alter test set not null;
|
|
delete from atacc1;
|
|
alter table atacc1 alter test set not null;
|
|
|
|
-- try altering a non-existent column, should fail
|
|
alter table atacc1 alter bar set not null;
|
|
alter table atacc1 alter bar drop not null;
|
|
|
|
-- try altering the oid column, should fail
|
|
alter table atacc1 alter oid set not null;
|
|
alter table atacc1 alter oid drop not null;
|
|
|
|
-- try creating a view and altering that, should fail
|
|
create view myview as select * from atacc1;
|
|
alter table myview alter column test drop not null;
|
|
alter table myview alter column test set not null;
|
|
drop view myview;
|
|
|
|
drop table atacc1;
|
|
|
|
-- test inheritance
|
|
create table parent (a int);
|
|
create table child (b varchar(255)) inherits (parent);
|
|
|
|
alter table parent alter a set not null;
|
|
insert into parent values (NULL);
|
|
insert into child (a, b) values (NULL, 'foo');
|
|
alter table parent alter a drop not null;
|
|
insert into parent values (NULL);
|
|
insert into child (a, b) values (NULL, 'foo');
|
|
alter table only parent alter a set not null;
|
|
alter table child alter a set not null;
|
|
delete from parent;
|
|
alter table only parent alter a set not null;
|
|
insert into parent values (NULL);
|
|
alter table child alter a set not null;
|
|
insert into child (a, b) values (NULL, 'foo');
|
|
delete from child;
|
|
alter table child alter a set not null;
|
|
insert into child (a, b) values (NULL, 'foo');
|
|
drop table child;
|
|
drop table parent;
|
|
|
|
-- test setting and removing default values
|
|
create table def_test (
|
|
c1 int4 default 5,
|
|
c2 text default 'initial_default'
|
|
);
|
|
insert into def_test default values;
|
|
alter table def_test alter column c1 drop default;
|
|
insert into def_test default values;
|
|
alter table def_test alter column c2 drop default;
|
|
insert into def_test default values;
|
|
alter table def_test alter column c1 set default 10;
|
|
alter table def_test alter column c2 set default 'new_default';
|
|
insert into def_test default values;
|
|
select * from def_test;
|
|
|
|
-- set defaults to an incorrect type: this should fail
|
|
alter table def_test alter column c1 set default 'wrong_datatype';
|
|
alter table def_test alter column c2 set default 20;
|
|
|
|
-- set defaults on a non-existent column: this should fail
|
|
alter table def_test alter column c3 set default 30;
|
|
|
|
-- set defaults on views: we need to create a view, add a rule
|
|
-- to allow insertions into it, and then alter the view to add
|
|
-- a default
|
|
create view def_view_test as select * from def_test;
|
|
create rule def_view_test_ins as
|
|
on insert to def_view_test
|
|
do instead insert into def_test select new.*;
|
|
insert into def_view_test default values;
|
|
alter table def_view_test alter column c1 set default 45;
|
|
insert into def_view_test default values;
|
|
alter table def_view_test alter column c2 set default 'view_default';
|
|
insert into def_view_test default values;
|
|
select * from def_view_test;
|
|
|
|
drop rule def_view_test_ins on def_view_test;
|
|
drop view def_view_test;
|
|
drop table def_test;
|
|
|
|
-- alter table / drop column tests
|
|
-- try altering system catalogs, should fail
|
|
alter table pg_class drop column relname;
|
|
|
|
-- try altering non-existent table, should fail
|
|
alter table foo drop column bar;
|
|
|
|
-- test dropping columns
|
|
create table atacc1 (a int4 not null, b int4, c int4 not null, d int4);
|
|
insert into atacc1 values (1, 2, 3, 4);
|
|
alter table atacc1 drop a;
|
|
alter table atacc1 drop a;
|
|
|
|
-- SELECTs
|
|
select * from atacc1;
|
|
select * from atacc1 order by a;
|
|
select * from atacc1 order by "........pg.dropped.1........";
|
|
select * from atacc1 group by a;
|
|
select * from atacc1 group by "........pg.dropped.1........";
|
|
select atacc1.* from atacc1;
|
|
select a from atacc1;
|
|
select atacc1.a from atacc1;
|
|
select b,c,d from atacc1;
|
|
select a,b,c,d from atacc1;
|
|
select * from atacc1 where a = 1;
|
|
select "........pg.dropped.1........" from atacc1;
|
|
select atacc1."........pg.dropped.1........" from atacc1;
|
|
select "........pg.dropped.1........",b,c,d from atacc1;
|
|
select * from atacc1 where "........pg.dropped.1........" = 1;
|
|
|
|
-- UPDATEs
|
|
update atacc1 set a = 3;
|
|
update atacc1 set b = 2 where a = 3;
|
|
update atacc1 set "........pg.dropped.1........" = 3;
|
|
update atacc1 set b = 2 where "........pg.dropped.1........" = 3;
|
|
|
|
-- INSERTs
|
|
insert into atacc1 values (10, 11, 12, 13);
|
|
insert into atacc1 values (default, 11, 12, 13);
|
|
insert into atacc1 values (11, 12, 13);
|
|
insert into atacc1 (a) values (10);
|
|
insert into atacc1 (a) values (default);
|
|
insert into atacc1 (a,b,c,d) values (10,11,12,13);
|
|
insert into atacc1 (a,b,c,d) values (default,11,12,13);
|
|
insert into atacc1 (b,c,d) values (11,12,13);
|
|
insert into atacc1 ("........pg.dropped.1........") values (10);
|
|
insert into atacc1 ("........pg.dropped.1........") values (default);
|
|
insert into atacc1 ("........pg.dropped.1........",b,c,d) values (10,11,12,13);
|
|
insert into atacc1 ("........pg.dropped.1........",b,c,d) values (default,11,12,13);
|
|
|
|
-- DELETEs
|
|
delete from atacc1 where a = 3;
|
|
delete from atacc1 where "........pg.dropped.1........" = 3;
|
|
delete from atacc1;
|
|
|
|
-- try dropping a non-existent column, should fail
|
|
alter table atacc1 drop bar;
|
|
|
|
-- try dropping the oid column, should fail
|
|
alter table atacc1 drop oid;
|
|
|
|
-- try creating a view and altering that, should fail
|
|
create view myview as select * from atacc1;
|
|
select * from myview;
|
|
alter table myview drop d;
|
|
drop view myview;
|
|
|
|
-- test some commands to make sure they fail on the dropped column
|
|
analyze atacc1(a);
|
|
analyze atacc1("........pg.dropped.1........");
|
|
vacuum analyze atacc1(a);
|
|
vacuum analyze atacc1("........pg.dropped.1........");
|
|
comment on column atacc1.a is 'testing';
|
|
comment on column atacc1."........pg.dropped.1........" is 'testing';
|
|
alter table atacc1 alter a set storage plain;
|
|
alter table atacc1 alter "........pg.dropped.1........" set storage plain;
|
|
alter table atacc1 alter a set statistics 0;
|
|
alter table atacc1 alter "........pg.dropped.1........" set statistics 0;
|
|
alter table atacc1 alter a set default 3;
|
|
alter table atacc1 alter "........pg.dropped.1........" set default 3;
|
|
alter table atacc1 alter a drop default;
|
|
alter table atacc1 alter "........pg.dropped.1........" drop default;
|
|
alter table atacc1 alter a set not null;
|
|
alter table atacc1 alter "........pg.dropped.1........" set not null;
|
|
alter table atacc1 alter a drop not null;
|
|
alter table atacc1 alter "........pg.dropped.1........" drop not null;
|
|
alter table atacc1 rename a to x;
|
|
alter table atacc1 rename "........pg.dropped.1........" to x;
|
|
alter table atacc1 add primary key(a);
|
|
alter table atacc1 add primary key("........pg.dropped.1........");
|
|
alter table atacc1 add unique(a);
|
|
alter table atacc1 add unique("........pg.dropped.1........");
|
|
alter table atacc1 add check (a > 3);
|
|
alter table atacc1 add check ("........pg.dropped.1........" > 3);
|
|
create table atacc2 (id int4 unique);
|
|
alter table atacc1 add foreign key (a) references atacc2(id);
|
|
alter table atacc1 add foreign key ("........pg.dropped.1........") references atacc2(id);
|
|
alter table atacc2 add foreign key (id) references atacc1(a);
|
|
alter table atacc2 add foreign key (id) references atacc1("........pg.dropped.1........");
|
|
drop table atacc2;
|
|
create index "testing_idx" on atacc1(a);
|
|
create index "testing_idx" on atacc1("........pg.dropped.1........");
|
|
|
|
-- test create as and select into
|
|
insert into atacc1 values (21, 22, 23);
|
|
create table test1 as select * from atacc1;
|
|
select * from test1;
|
|
drop table test1;
|
|
select * into test2 from atacc1;
|
|
select * from test2;
|
|
drop table test2;
|
|
|
|
-- try dropping all columns
|
|
alter table atacc1 drop c;
|
|
alter table atacc1 drop d;
|
|
alter table atacc1 drop b;
|
|
select * from atacc1;
|
|
|
|
drop table atacc1;
|
|
|
|
-- test inheritance
|
|
create table parent (a int, b int, c int);
|
|
insert into parent values (1, 2, 3);
|
|
alter table parent drop a;
|
|
create table child (d varchar(255)) inherits (parent);
|
|
insert into child values (12, 13, 'testing');
|
|
|
|
select * from parent;
|
|
select * from child;
|
|
alter table parent drop c;
|
|
select * from parent;
|
|
select * from child;
|
|
|
|
drop table child;
|
|
drop table parent;
|
|
|
|
-- test copy in/out
|
|
create table test (a int4, b int4, c int4);
|
|
insert into test values (1,2,3);
|
|
alter table test drop a;
|
|
copy test to stdout;
|
|
copy test(a) to stdout;
|
|
copy test("........pg.dropped.1........") to stdout;
|
|
copy test from stdin;
|
|
10 11 12
|
|
\.
|
|
select * from test;
|
|
copy test from stdin;
|
|
21 22
|
|
\.
|
|
select * from test;
|
|
copy test(a) from stdin;
|
|
copy test("........pg.dropped.1........") from stdin;
|
|
copy test(b,c) from stdin;
|
|
31 32
|
|
\.
|
|
select * from test;
|
|
drop table test;
|
|
|