mirror of
https://github.com/postgres/postgres.git
synced 2025-05-08 07:21:33 +03:00
When a tablespace is used in a partitioned relation (per commits ca4103025dfe in pg12 for tables and 33e6c34c3267 in pg11 for indexes), it is possible to drop the tablespace, potentially causing various problems. One such was reported in bug #16577, where a rewriting ALTER TABLE causes a server crash. Protect against this by using pg_shdepend to keep track of tablespaces when used for relations that don't keep physical files; we now abort a tablespace if we see that the tablespace is referenced from any partitioned relations. Backpatch this to 11, where this problem has been latent all along. We don't try to create pg_shdepend entries for existing partitioned indexes/tables, but any ones that are modified going forward will be protected. Note slight behavior change: when trying to drop a tablespace that contains both regular tables as well as partitioned ones, you'd previously get ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE and now you'll get ERRCODE_DEPENDENT_OBJECTS_STILL_EXIST. Arguably, the latter is more correct. It is possible to add protecting pg_shdepend entries for existing tables/indexes, by doing ALTER TABLE ONLY some_partitioned_table SET TABLESPACE pg_default; ALTER TABLE ONLY some_partitioned_table SET TABLESPACE original_tablespace; for each partitioned table/index that is not in the database default tablespace. Because these partitioned objects do not have storage, no file needs to be actually moved, so it shouldn't take more time than what's required to acquire locks. This query can be used to search for such relations: SELECT ... FROM pg_class WHERE relkind IN ('p', 'I') AND reltablespace <> 0 Reported-by: Alexander Lakhin <exclusion@gmail.com> Discussion: https://postgr.es/m/16577-881633a9f9894fd5@postgresql.org Author: Álvaro Herrera <alvherre@alvh.no-ip.org> Reviewed-by: Michael Paquier <michael@paquier.xyz>
280 lines
12 KiB
Plaintext
280 lines
12 KiB
Plaintext
-- create a tablespace using WITH clause
|
|
CREATE TABLESPACE regress_tblspacewith LOCATION '@testtablespace@' WITH (some_nonexistent_parameter = true); -- fail
|
|
CREATE TABLESPACE regress_tblspacewith LOCATION '@testtablespace@' WITH (random_page_cost = 3.0); -- ok
|
|
|
|
-- check to see the parameter was used
|
|
SELECT spcoptions FROM pg_tablespace WHERE spcname = 'regress_tblspacewith';
|
|
|
|
-- drop the tablespace so we can re-use the location
|
|
DROP TABLESPACE regress_tblspacewith;
|
|
|
|
-- create a tablespace we can use
|
|
CREATE TABLESPACE regress_tblspace LOCATION '@testtablespace@';
|
|
|
|
-- try setting and resetting some properties for the new tablespace
|
|
ALTER TABLESPACE regress_tblspace SET (random_page_cost = 1.0, seq_page_cost = 1.1);
|
|
ALTER TABLESPACE regress_tblspace SET (some_nonexistent_parameter = true); -- fail
|
|
ALTER TABLESPACE regress_tblspace RESET (random_page_cost = 2.0); -- fail
|
|
ALTER TABLESPACE regress_tblspace RESET (random_page_cost, effective_io_concurrency); -- ok
|
|
|
|
-- create a schema we can use
|
|
CREATE SCHEMA testschema;
|
|
|
|
-- try a table
|
|
CREATE TABLE testschema.foo (i int) TABLESPACE regress_tblspace;
|
|
SELECT relname, spcname FROM pg_catalog.pg_tablespace t, pg_catalog.pg_class c
|
|
where c.reltablespace = t.oid AND c.relname = 'foo';
|
|
|
|
INSERT INTO testschema.foo VALUES(1);
|
|
INSERT INTO testschema.foo VALUES(2);
|
|
|
|
-- tables from dynamic sources
|
|
CREATE TABLE testschema.asselect TABLESPACE regress_tblspace AS SELECT 1;
|
|
SELECT relname, spcname FROM pg_catalog.pg_tablespace t, pg_catalog.pg_class c
|
|
where c.reltablespace = t.oid AND c.relname = 'asselect';
|
|
|
|
PREPARE selectsource(int) AS SELECT $1;
|
|
CREATE TABLE testschema.asexecute TABLESPACE regress_tblspace
|
|
AS EXECUTE selectsource(2);
|
|
SELECT relname, spcname FROM pg_catalog.pg_tablespace t, pg_catalog.pg_class c
|
|
where c.reltablespace = t.oid AND c.relname = 'asexecute';
|
|
|
|
-- index
|
|
CREATE INDEX foo_idx on testschema.foo(i) TABLESPACE regress_tblspace;
|
|
SELECT relname, spcname FROM pg_catalog.pg_tablespace t, pg_catalog.pg_class c
|
|
where c.reltablespace = t.oid AND c.relname = 'foo_idx';
|
|
|
|
--
|
|
-- partitioned table
|
|
--
|
|
CREATE TABLE testschema.part (a int) PARTITION BY LIST (a);
|
|
SET default_tablespace TO pg_global;
|
|
CREATE TABLE testschema.part_1 PARTITION OF testschema.part FOR VALUES IN (1);
|
|
RESET default_tablespace;
|
|
CREATE TABLE testschema.part_1 PARTITION OF testschema.part FOR VALUES IN (1);
|
|
SET default_tablespace TO regress_tblspace;
|
|
CREATE TABLE testschema.part_2 PARTITION OF testschema.part FOR VALUES IN (2);
|
|
SET default_tablespace TO pg_global;
|
|
CREATE TABLE testschema.part_3 PARTITION OF testschema.part FOR VALUES IN (3);
|
|
ALTER TABLE testschema.part SET TABLESPACE regress_tblspace;
|
|
CREATE TABLE testschema.part_3 PARTITION OF testschema.part FOR VALUES IN (3);
|
|
CREATE TABLE testschema.part_4 PARTITION OF testschema.part FOR VALUES IN (4)
|
|
TABLESPACE pg_default;
|
|
CREATE TABLE testschema.part_56 PARTITION OF testschema.part FOR VALUES IN (5, 6)
|
|
PARTITION BY LIST (a);
|
|
ALTER TABLE testschema.part SET TABLESPACE pg_default;
|
|
CREATE TABLE testschema.part_78 PARTITION OF testschema.part FOR VALUES IN (7, 8)
|
|
PARTITION BY LIST (a);
|
|
CREATE TABLE testschema.part_910 PARTITION OF testschema.part FOR VALUES IN (9, 10)
|
|
PARTITION BY LIST (a) TABLESPACE regress_tblspace;
|
|
RESET default_tablespace;
|
|
CREATE TABLE testschema.part_78 PARTITION OF testschema.part FOR VALUES IN (7, 8)
|
|
PARTITION BY LIST (a);
|
|
|
|
SELECT relname, spcname FROM pg_catalog.pg_class c
|
|
JOIN pg_catalog.pg_namespace n ON (c.relnamespace = n.oid)
|
|
LEFT JOIN pg_catalog.pg_tablespace t ON c.reltablespace = t.oid
|
|
where c.relname LIKE 'part%' AND n.nspname = 'testschema' order by relname;
|
|
RESET default_tablespace;
|
|
DROP TABLE testschema.part;
|
|
|
|
-- partitioned index
|
|
CREATE TABLE testschema.part (a int) PARTITION BY LIST (a);
|
|
CREATE TABLE testschema.part1 PARTITION OF testschema.part FOR VALUES IN (1);
|
|
CREATE INDEX part_a_idx ON testschema.part (a) TABLESPACE regress_tblspace;
|
|
CREATE TABLE testschema.part2 PARTITION OF testschema.part FOR VALUES IN (2);
|
|
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 '';
|
|
-- tablespace should not change if no 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
|
|
-- 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);
|
|
SET default_tablespace TO regress_tblspace;
|
|
ALTER TABLE testschema.test_tab ADD CONSTRAINT test_tab_unique UNIQUE (id);
|
|
SET default_tablespace TO '';
|
|
ALTER TABLE testschema.test_tab ADD CONSTRAINT test_tab_pkey PRIMARY KEY (id);
|
|
\d testschema.test_tab_unique
|
|
\d testschema.test_tab_pkey
|
|
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);
|
|
|
|
ALTER TABLE testschema.atable SET TABLESPACE regress_tblspace;
|
|
ALTER INDEX testschema.anindex SET TABLESPACE regress_tblspace;
|
|
ALTER INDEX testschema.part_a_idx SET TABLESPACE pg_global;
|
|
ALTER INDEX testschema.part_a_idx SET TABLESPACE pg_default;
|
|
ALTER INDEX testschema.part_a_idx SET TABLESPACE regress_tblspace;
|
|
|
|
INSERT INTO testschema.atable VALUES(3); -- ok
|
|
INSERT INTO testschema.atable VALUES(1); -- fail (checks index)
|
|
SELECT COUNT(*) FROM testschema.atable; -- checks heap
|
|
|
|
-- Will fail with bad path
|
|
CREATE TABLESPACE regress_badspace LOCATION '/no/such/location';
|
|
|
|
-- No such tablespace
|
|
CREATE TABLE bar (i int) TABLESPACE regress_nosuchspace;
|
|
|
|
-- Fail, in use for some partitioned object
|
|
DROP TABLESPACE regress_tblspace;
|
|
ALTER INDEX testschema.part_a_idx SET TABLESPACE pg_default;
|
|
-- Fail, not empty
|
|
DROP TABLESPACE regress_tblspace;
|
|
|
|
CREATE ROLE regress_tablespace_user1 login;
|
|
CREATE ROLE regress_tablespace_user2 login;
|
|
GRANT USAGE ON SCHEMA testschema TO regress_tablespace_user2;
|
|
|
|
ALTER TABLESPACE regress_tblspace OWNER TO regress_tablespace_user1;
|
|
|
|
CREATE TABLE testschema.tablespace_acl (c int);
|
|
-- new owner lacks permission to create this index from scratch
|
|
CREATE INDEX k ON testschema.tablespace_acl (c) TABLESPACE regress_tblspace;
|
|
ALTER TABLE testschema.tablespace_acl OWNER TO regress_tablespace_user2;
|
|
|
|
SET SESSION ROLE regress_tablespace_user2;
|
|
CREATE TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail
|
|
ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint;
|
|
RESET ROLE;
|
|
|
|
ALTER TABLESPACE regress_tblspace RENAME TO regress_tblspace_renamed;
|
|
|
|
ALTER TABLE ALL IN TABLESPACE regress_tblspace_renamed SET TABLESPACE pg_default;
|
|
ALTER INDEX ALL IN TABLESPACE regress_tblspace_renamed SET TABLESPACE pg_default;
|
|
|
|
-- Should show notice that nothing was done
|
|
ALTER TABLE ALL IN TABLESPACE regress_tblspace_renamed SET TABLESPACE pg_default;
|
|
|
|
-- Should succeed
|
|
DROP TABLESPACE regress_tblspace_renamed;
|
|
|
|
DROP SCHEMA testschema CASCADE;
|
|
|
|
DROP ROLE regress_tablespace_user1;
|
|
DROP ROLE regress_tablespace_user2;
|