1
0
mirror of https://github.com/postgres/postgres.git synced 2025-12-10 14:22:35 +03:00

Fix tablespace inheritance for partitioned rels

Commit ca4103025d left a few loose ends.  The most important one
(broken pg_dump output) is already fixed by virtue of commit
3b23552ad8, but some things remained:

* When ALTER TABLE rewrites tables, the indexes must remain in the
  tablespace they were originally in.  This didn't work because
  index recreation during ALTER TABLE runs manufactured SQL (yuck),
  which runs afoul of default_tablespace in competition with the parent
  relation tablespace.  To fix, reset default_tablespace to the empty
  string temporarily, and add the TABLESPACE clause as appropriate.

* Setting a partitioned rel's tablespace to the database default is
  confusing; if it worked, it would direct the partitions to that
  tablespace regardless of default_tablespace.  But in reality it does
  not work, and making it work is a larger project.  Therefore, throw
  an error when this condition is detected, to alert the unwary.

Add some docs and tests, too.

Author: Álvaro Herrera
Discussion: https://postgr.es/m/CAKJS1f_1c260nOt_vBJ067AZ3JXptXVRohDVMLEBmudX1YEx-A@mail.gmail.com
This commit is contained in:
Alvaro Herrera
2019-04-25 10:20:23 -04:00
parent 3b23552ad8
commit 87259588d0
18 changed files with 519 additions and 34 deletions

View File

@@ -65,24 +65,45 @@ SELECT relname, spcname FROM pg_catalog.pg_tablespace t, pg_catalog.pg_class c
where c.reltablespace = t.oid AND c.relname LIKE 'part%_idx';
\d testschema.part_a_idx
-- partitioned rels cannot specify the default tablespace. These fail:
CREATE TABLE testschema.dflt (a int PRIMARY KEY) PARTITION BY LIST (a) TABLESPACE pg_default;
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE pg_default) PARTITION BY LIST (a);
SET default_tablespace TO 'pg_default';
CREATE TABLE testschema.dflt (a int PRIMARY KEY) PARTITION BY LIST (a) TABLESPACE regress_tblspace;
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) PARTITION BY LIST (a);
-- but these work:
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) PARTITION BY LIST (a) TABLESPACE regress_tblspace;
SET default_tablespace TO '';
CREATE TABLE testschema.dflt2 (a int PRIMARY KEY) PARTITION BY LIST (a);
DROP TABLE testschema.dflt, testschema.dflt2;
-- check that default_tablespace doesn't affect ALTER TABLE index rebuilds
CREATE TABLE testschema.test_default_tab(id bigint) TABLESPACE regress_tblspace;
INSERT INTO testschema.test_default_tab VALUES (1);
CREATE INDEX test_index1 on testschema.test_default_tab (id);
CREATE INDEX test_index2 on testschema.test_default_tab (id) TABLESPACE regress_tblspace;
ALTER TABLE testschema.test_default_tab ADD CONSTRAINT test_index3 PRIMARY KEY (id);
ALTER TABLE testschema.test_default_tab ADD CONSTRAINT test_index4 UNIQUE (id) USING INDEX TABLESPACE regress_tblspace;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
-- use a custom tablespace for default_tablespace
SET default_tablespace TO regress_tblspace;
-- tablespace should not change if no rewrite
ALTER TABLE testschema.test_default_tab ALTER id TYPE bigint;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
SELECT * FROM testschema.test_default_tab;
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab ALTER id TYPE int;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
SELECT * FROM testschema.test_default_tab;
-- now use the default tablespace for default_tablespace
SET default_tablespace TO '';
@@ -90,12 +111,64 @@ SET default_tablespace TO '';
ALTER TABLE testschema.test_default_tab ALTER id TYPE int;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab ALTER id TYPE bigint;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
DROP TABLE testschema.test_default_tab;
-- check that default_tablespace doesn't affect ALTER TABLE index rebuilds
-- (this time with a partitioned table)
CREATE TABLE testschema.test_default_tab_p(id bigint, val bigint)
PARTITION BY LIST (id) TABLESPACE regress_tblspace;
CREATE TABLE testschema.test_default_tab_p1 PARTITION OF testschema.test_default_tab_p
FOR VALUES IN (1);
INSERT INTO testschema.test_default_tab_p VALUES (1);
CREATE INDEX test_index1 on testschema.test_default_tab_p (val);
CREATE INDEX test_index2 on testschema.test_default_tab_p (val) TABLESPACE regress_tblspace;
ALTER TABLE testschema.test_default_tab_p ADD CONSTRAINT test_index3 PRIMARY KEY (id);
ALTER TABLE testschema.test_default_tab_p ADD CONSTRAINT test_index4 UNIQUE (id) USING INDEX TABLESPACE regress_tblspace;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
-- use a custom tablespace for default_tablespace
SET default_tablespace TO regress_tblspace;
-- tablespace should not change if no rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE bigint;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
SELECT * FROM testschema.test_default_tab_p;
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE int;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
SELECT * FROM testschema.test_default_tab_p;
-- now use the default tablespace for default_tablespace
SET default_tablespace TO '';
-- tablespace should not change if no rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE int;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE bigint;
\d testschema.test_index1
\d testschema.test_index2
\d testschema.test_index3
\d testschema.test_index4
DROP TABLE testschema.test_default_tab_p;
-- check that default_tablespace affects index additions in ALTER TABLE
CREATE TABLE testschema.test_tab(id int) TABLESPACE regress_tblspace;
INSERT INTO testschema.test_tab VALUES (1);
@@ -108,6 +181,23 @@ ALTER TABLE testschema.test_tab ADD CONSTRAINT test_tab_pkey PRIMARY KEY (id);
SELECT * FROM testschema.test_tab;
DROP TABLE testschema.test_tab;
-- check that default_tablespace is handled correctly by multi-command
-- ALTER TABLE that includes a tablespace-preserving rewrite
CREATE TABLE testschema.test_tab(a int, b int, c int);
SET default_tablespace TO regress_tblspace;
ALTER TABLE testschema.test_tab ADD CONSTRAINT test_tab_unique UNIQUE (a);
CREATE INDEX test_tab_a_idx ON testschema.test_tab (a);
SET default_tablespace TO '';
CREATE INDEX test_tab_b_idx ON testschema.test_tab (b);
\d testschema.test_tab_unique
\d testschema.test_tab_a_idx
\d testschema.test_tab_b_idx
ALTER TABLE testschema.test_tab ALTER b TYPE bigint, ADD UNIQUE (c);
\d testschema.test_tab_unique
\d testschema.test_tab_a_idx
\d testschema.test_tab_b_idx
DROP TABLE testschema.test_tab;
-- let's try moving a table from one place to another
CREATE TABLE testschema.atable AS VALUES (1), (2);
CREATE UNIQUE INDEX anindex ON testschema.atable(column1);

View File

@@ -102,11 +102,28 @@ Partitioned index "testschema.part_a_idx"
btree, for table "testschema.part"
Tablespace: "regress_tblspace"
-- partitioned rels cannot specify the default tablespace. These fail:
CREATE TABLE testschema.dflt (a int PRIMARY KEY) PARTITION BY LIST (a) TABLESPACE pg_default;
ERROR: cannot specify default tablespace for partitioned relations
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE pg_default) PARTITION BY LIST (a);
ERROR: cannot specify default tablespace for partitioned relation
SET default_tablespace TO 'pg_default';
CREATE TABLE testschema.dflt (a int PRIMARY KEY) PARTITION BY LIST (a) TABLESPACE regress_tblspace;
ERROR: cannot specify default tablespace for partitioned relations
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) PARTITION BY LIST (a);
ERROR: cannot specify default tablespace for partitioned relations
-- but these work:
CREATE TABLE testschema.dflt (a int PRIMARY KEY USING INDEX TABLESPACE regress_tblspace) PARTITION BY LIST (a) TABLESPACE regress_tblspace;
SET default_tablespace TO '';
CREATE TABLE testschema.dflt2 (a int PRIMARY KEY) PARTITION BY LIST (a);
DROP TABLE testschema.dflt, testschema.dflt2;
-- check that default_tablespace doesn't affect ALTER TABLE index rebuilds
CREATE TABLE testschema.test_default_tab(id bigint) TABLESPACE regress_tblspace;
INSERT INTO testschema.test_default_tab VALUES (1);
CREATE INDEX test_index1 on testschema.test_default_tab (id);
CREATE INDEX test_index2 on testschema.test_default_tab (id) TABLESPACE regress_tblspace;
ALTER TABLE testschema.test_default_tab ADD CONSTRAINT test_index3 PRIMARY KEY (id);
ALTER TABLE testschema.test_default_tab ADD CONSTRAINT test_index4 UNIQUE (id) USING INDEX TABLESPACE regress_tblspace;
\d testschema.test_index1
Index "testschema.test_index1"
Column | Type | Key? | Definition
@@ -122,6 +139,21 @@ btree, for table "testschema.test_default_tab"
btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab"
\d testschema.test_index4
Index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
-- use a custom tablespace for default_tablespace
SET default_tablespace TO regress_tblspace;
-- tablespace should not change if no rewrite
@@ -141,6 +173,21 @@ btree, for table "testschema.test_default_tab"
btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab"
\d testschema.test_index4
Index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
SELECT * FROM testschema.test_default_tab;
id
----
@@ -164,6 +211,21 @@ btree, for table "testschema.test_default_tab"
btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Index "testschema.test_index3"
Column | Type | Key? | Definition
--------+---------+------+------------
id | integer | yes | id
primary key, btree, for table "testschema.test_default_tab"
\d testschema.test_index4
Index "testschema.test_index4"
Column | Type | Key? | Definition
--------+---------+------+------------
id | integer | yes | id
unique, btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
SELECT * FROM testschema.test_default_tab;
id
----
@@ -189,6 +251,21 @@ btree, for table "testschema.test_default_tab"
btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Index "testschema.test_index3"
Column | Type | Key? | Definition
--------+---------+------+------------
id | integer | yes | id
primary key, btree, for table "testschema.test_default_tab"
\d testschema.test_index4
Index "testschema.test_index4"
Column | Type | Key? | Definition
--------+---------+------+------------
id | integer | yes | id
unique, btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab ALTER id TYPE bigint;
\d testschema.test_index1
@@ -206,7 +283,208 @@ btree, for table "testschema.test_default_tab"
btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab"
\d testschema.test_index4
Index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab"
Tablespace: "regress_tblspace"
DROP TABLE testschema.test_default_tab;
-- check that default_tablespace doesn't affect ALTER TABLE index rebuilds
-- (this time with a partitioned table)
CREATE TABLE testschema.test_default_tab_p(id bigint, val bigint)
PARTITION BY LIST (id) TABLESPACE regress_tblspace;
CREATE TABLE testschema.test_default_tab_p1 PARTITION OF testschema.test_default_tab_p
FOR VALUES IN (1);
INSERT INTO testschema.test_default_tab_p VALUES (1);
CREATE INDEX test_index1 on testschema.test_default_tab_p (val);
CREATE INDEX test_index2 on testschema.test_default_tab_p (val) TABLESPACE regress_tblspace;
ALTER TABLE testschema.test_default_tab_p ADD CONSTRAINT test_index3 PRIMARY KEY (id);
ALTER TABLE testschema.test_default_tab_p ADD CONSTRAINT test_index4 UNIQUE (id) USING INDEX TABLESPACE regress_tblspace;
\d testschema.test_index1
Partitioned index "testschema.test_index1"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
\d testschema.test_index2
Partitioned index "testschema.test_index2"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Partitioned index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab_p"
\d testschema.test_index4
Partitioned index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
-- use a custom tablespace for default_tablespace
SET default_tablespace TO regress_tblspace;
-- tablespace should not change if no rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE bigint;
\d testschema.test_index1
Partitioned index "testschema.test_index1"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
\d testschema.test_index2
Partitioned index "testschema.test_index2"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Partitioned index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab_p"
\d testschema.test_index4
Partitioned index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
SELECT * FROM testschema.test_default_tab_p;
id | val
----+-----
1 |
(1 row)
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE int;
\d testschema.test_index1
Partitioned index "testschema.test_index1"
Column | Type | Key? | Definition
--------+---------+------+------------
val | integer | yes | val
btree, for table "testschema.test_default_tab_p"
\d testschema.test_index2
Partitioned index "testschema.test_index2"
Column | Type | Key? | Definition
--------+---------+------+------------
val | integer | yes | val
btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Partitioned index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab_p"
\d testschema.test_index4
Partitioned index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
SELECT * FROM testschema.test_default_tab_p;
id | val
----+-----
1 |
(1 row)
-- now use the default tablespace for default_tablespace
SET default_tablespace TO '';
-- tablespace should not change if no rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE int;
\d testschema.test_index1
Partitioned index "testschema.test_index1"
Column | Type | Key? | Definition
--------+---------+------+------------
val | integer | yes | val
btree, for table "testschema.test_default_tab_p"
\d testschema.test_index2
Partitioned index "testschema.test_index2"
Column | Type | Key? | Definition
--------+---------+------+------------
val | integer | yes | val
btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Partitioned index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab_p"
\d testschema.test_index4
Partitioned index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
-- tablespace should not change even if there is an index rewrite
ALTER TABLE testschema.test_default_tab_p ALTER val TYPE bigint;
\d testschema.test_index1
Partitioned index "testschema.test_index1"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
\d testschema.test_index2
Partitioned index "testschema.test_index2"
Column | Type | Key? | Definition
--------+--------+------+------------
val | bigint | yes | val
btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
\d testschema.test_index3
Partitioned index "testschema.test_index3"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
primary key, btree, for table "testschema.test_default_tab_p"
\d testschema.test_index4
Partitioned index "testschema.test_index4"
Column | Type | Key? | Definition
--------+--------+------+------------
id | bigint | yes | id
unique, btree, for table "testschema.test_default_tab_p"
Tablespace: "regress_tblspace"
DROP TABLE testschema.test_default_tab_p;
-- check that default_tablespace affects index additions in ALTER TABLE
CREATE TABLE testschema.test_tab(id int) TABLESPACE regress_tblspace;
INSERT INTO testschema.test_tab VALUES (1);
@@ -235,6 +513,62 @@ SELECT * FROM testschema.test_tab;
1
(1 row)
DROP TABLE testschema.test_tab;
-- check that default_tablespace is handled correctly by multi-command
-- ALTER TABLE that includes a tablespace-preserving rewrite
CREATE TABLE testschema.test_tab(a int, b int, c int);
SET default_tablespace TO regress_tblspace;
ALTER TABLE testschema.test_tab ADD CONSTRAINT test_tab_unique UNIQUE (a);
CREATE INDEX test_tab_a_idx ON testschema.test_tab (a);
SET default_tablespace TO '';
CREATE INDEX test_tab_b_idx ON testschema.test_tab (b);
\d testschema.test_tab_unique
Index "testschema.test_tab_unique"
Column | Type | Key? | Definition
--------+---------+------+------------
a | integer | yes | a
unique, btree, for table "testschema.test_tab"
Tablespace: "regress_tblspace"
\d testschema.test_tab_a_idx
Index "testschema.test_tab_a_idx"
Column | Type | Key? | Definition
--------+---------+------+------------
a | integer | yes | a
btree, for table "testschema.test_tab"
Tablespace: "regress_tblspace"
\d testschema.test_tab_b_idx
Index "testschema.test_tab_b_idx"
Column | Type | Key? | Definition
--------+---------+------+------------
b | integer | yes | b
btree, for table "testschema.test_tab"
ALTER TABLE testschema.test_tab ALTER b TYPE bigint, ADD UNIQUE (c);
\d testschema.test_tab_unique
Index "testschema.test_tab_unique"
Column | Type | Key? | Definition
--------+---------+------+------------
a | integer | yes | a
unique, btree, for table "testschema.test_tab"
Tablespace: "regress_tblspace"
\d testschema.test_tab_a_idx
Index "testschema.test_tab_a_idx"
Column | Type | Key? | Definition
--------+---------+------+------------
a | integer | yes | a
btree, for table "testschema.test_tab"
Tablespace: "regress_tblspace"
\d testschema.test_tab_b_idx
Index "testschema.test_tab_b_idx"
Column | Type | Key? | Definition
--------+--------+------+------------
b | bigint | yes | b
btree, for table "testschema.test_tab"
DROP TABLE testschema.test_tab;
-- let's try moving a table from one place to another
CREATE TABLE testschema.atable AS VALUES (1), (2);