Add TABLESPACE option to REINDEX
This patch adds the possibility to move indexes to a new tablespace while rebuilding them. Both the concurrent and the non-concurrent cases are supported, and the following set of restrictions apply: - When using TABLESPACE with a REINDEX command that targets a partitioned table or index, all the indexes of the leaf partitions are moved to the new tablespace. The tablespace references of the non-leaf, partitioned tables in pg_class.reltablespace are not changed. This requires an extra ALTER TABLE SET TABLESPACE. - Any index on a toast table rebuilt as part of a parent table is kept in its original tablespace. - The operation is forbidden on system catalogs, including trying to directly move a toast relation with REINDEX. This results in an error if doing REINDEX on a single object. REINDEX SCHEMA, DATABASE and SYSTEM skip system relations when TABLESPACE is used. Author: Alexey Kondratov, Michael Paquier, Justin Pryzby Reviewed-by: Álvaro Herrera, Michael Paquier Discussion: https://postgr.es/m/8a8f5f73-00d3-55f8-7583-1375ca8f6a91@postgrespro.ru
This commit is contained in:
parent
9624321ec5
commit
c5b286047c
@ -26,6 +26,7 @@ REINDEX [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] { IN
|
||||
<phrase>where <replaceable class="parameter">option</replaceable> can be one of:</phrase>
|
||||
|
||||
CONCURRENTLY [ <replaceable class="parameter">boolean</replaceable> ]
|
||||
TABLESPACE <replaceable class="parameter">new_tablespace</replaceable>
|
||||
VERBOSE [ <replaceable class="parameter">boolean</replaceable> ]
|
||||
</synopsis>
|
||||
</refsynopsisdiv>
|
||||
@ -187,6 +188,15 @@ REINDEX [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] { IN
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>TABLESPACE</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Specifies that indexes will be rebuilt on a new tablespace.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>VERBOSE</literal></term>
|
||||
<listitem>
|
||||
@ -210,6 +220,14 @@ REINDEX [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] { IN
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">new_tablespace</replaceable></term>
|
||||
<listitem>
|
||||
<para>
|
||||
The tablespace where indexes will be rebuilt.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
</variablelist>
|
||||
</refsect1>
|
||||
|
||||
@ -294,7 +312,27 @@ REINDEX [ ( <replaceable class="parameter">option</replaceable> [, ...] ) ] { IN
|
||||
reindexed in a separate transaction. Those commands cannot be used inside
|
||||
a transaction block when working on a partitioned table or index.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
When using the <literal>TABLESPACE</literal> clause with
|
||||
<command>REINDEX</command> on a partitioned index or table, only the
|
||||
tablespace references of the leaf partitions are updated. As partitioned
|
||||
indexes are not updated, it is recommended to separately use
|
||||
<command>ALTER TABLE ONLY</command> on them so as any new partitions
|
||||
attached inherit the new tablespace. On failure, it may not have moved
|
||||
all the indexes to the new tablespace. Re-running the command will rebuild
|
||||
all the leaf partitions and move previously-unprocessed indexes to the new
|
||||
tablespace.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
If <literal>SCHEMA</literal>, <literal>DATABASE</literal> or
|
||||
<literal>SYSTEM</literal> is used with <literal>TABLESPACE</literal>,
|
||||
system relations are skipped and a single <literal>WARNING</literal>
|
||||
will be generated. Indexes on TOAST tables are rebuilt, but not moved
|
||||
to the new tablespace.
|
||||
</para>
|
||||
|
||||
<refsect2 id="sql-reindex-concurrently" xreflabel="Rebuilding Indexes Concurrently">
|
||||
<title>Rebuilding Indexes Concurrently</title>
|
||||
|
||||
|
@ -57,6 +57,7 @@
|
||||
#include "commands/event_trigger.h"
|
||||
#include "commands/progress.h"
|
||||
#include "commands/tablecmds.h"
|
||||
#include "commands/tablespace.h"
|
||||
#include "commands/trigger.h"
|
||||
#include "executor/executor.h"
|
||||
#include "miscadmin.h"
|
||||
@ -1394,9 +1395,12 @@ index_update_collation_versions(Oid relid, Oid coll)
|
||||
* Create concurrently an index based on the definition of the one provided by
|
||||
* caller. The index is inserted into catalogs and needs to be built later
|
||||
* on. This is called during concurrent reindex processing.
|
||||
*
|
||||
* "tablespaceOid" is the tablespace to use for this index.
|
||||
*/
|
||||
Oid
|
||||
index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId, const char *newName)
|
||||
index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId,
|
||||
Oid tablespaceOid, const char *newName)
|
||||
{
|
||||
Relation indexRelation;
|
||||
IndexInfo *oldInfo,
|
||||
@ -1526,7 +1530,7 @@ index_concurrently_create_copy(Relation heapRelation, Oid oldIndexId, const char
|
||||
newInfo,
|
||||
indexColNames,
|
||||
indexRelation->rd_rel->relam,
|
||||
indexRelation->rd_rel->reltablespace,
|
||||
tablespaceOid,
|
||||
indexRelation->rd_indcollation,
|
||||
indclass->values,
|
||||
indcoloptions->values,
|
||||
@ -3603,6 +3607,7 @@ reindex_index(Oid indexId, bool skip_constraint_checks, char persistence,
|
||||
volatile bool skipped_constraint = false;
|
||||
PGRUsage ru0;
|
||||
bool progress = ((params->options & REINDEXOPT_REPORT_PROGRESS) != 0);
|
||||
bool set_tablespace = false;
|
||||
|
||||
pg_rusage_init(&ru0);
|
||||
|
||||
@ -3674,12 +3679,45 @@ reindex_index(Oid indexId, bool skip_constraint_checks, char persistence,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot reindex invalid index on TOAST table")));
|
||||
|
||||
/*
|
||||
* System relations cannot be moved even if allow_system_table_mods is
|
||||
* enabled to keep things consistent with the concurrent case where all
|
||||
* the indexes of a relation are processed in series, including indexes of
|
||||
* toast relations.
|
||||
*
|
||||
* Note that this check is not part of CheckRelationTableSpaceMove() as it
|
||||
* gets used for ALTER TABLE SET TABLESPACE that could cascade across
|
||||
* toast relations.
|
||||
*/
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
IsSystemRelation(iRel))
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot move system relation \"%s\"",
|
||||
RelationGetRelationName(iRel))));
|
||||
|
||||
/* Check if the tablespace of this index needs to be changed */
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
CheckRelationTableSpaceMove(iRel, params->tablespaceOid))
|
||||
set_tablespace = true;
|
||||
|
||||
/*
|
||||
* Also check for active uses of the index in the current transaction; we
|
||||
* don't want to reindex underneath an open indexscan.
|
||||
*/
|
||||
CheckTableNotInUse(iRel, "REINDEX INDEX");
|
||||
|
||||
/* Set new tablespace, if requested */
|
||||
if (set_tablespace)
|
||||
{
|
||||
/* Update its pg_class row */
|
||||
SetRelationTableSpace(iRel, params->tablespaceOid, InvalidOid);
|
||||
RelationAssumeNewRelfilenode(iRel);
|
||||
|
||||
/* Make sure the reltablespace change is visible */
|
||||
CommandCounterIncrement();
|
||||
}
|
||||
|
||||
/*
|
||||
* All predicate locks on the index are about to be made invalid. Promote
|
||||
* them to relation locks on the heap.
|
||||
@ -3963,11 +4001,14 @@ reindex_relation(Oid relid, int flags, ReindexParams *params)
|
||||
{
|
||||
/*
|
||||
* Note that this should fail if the toast relation is missing, so
|
||||
* reset REINDEXOPT_MISSING_OK.
|
||||
* reset REINDEXOPT_MISSING_OK. Even if a new tablespace is set for
|
||||
* the parent relation, the indexes on its toast table are not moved.
|
||||
* This rule is enforced by setting tablespaceOid to InvalidOid.
|
||||
*/
|
||||
ReindexParams newparams = *params;
|
||||
|
||||
newparams.options &= ~(REINDEXOPT_MISSING_OK);
|
||||
newparams.tablespaceOid = InvalidOid;
|
||||
result |= reindex_relation(toast_relid, flags, &newparams);
|
||||
}
|
||||
|
||||
|
@ -2474,6 +2474,7 @@ ExecReindex(ParseState *pstate, ReindexStmt *stmt, bool isTopLevel)
|
||||
ListCell *lc;
|
||||
bool concurrently = false;
|
||||
bool verbose = false;
|
||||
char *tablespacename = NULL;
|
||||
|
||||
/* Parse option list */
|
||||
foreach(lc, stmt->params)
|
||||
@ -2484,6 +2485,8 @@ ExecReindex(ParseState *pstate, ReindexStmt *stmt, bool isTopLevel)
|
||||
verbose = defGetBoolean(opt);
|
||||
else if (strcmp(opt->defname, "concurrently") == 0)
|
||||
concurrently = defGetBoolean(opt);
|
||||
else if (strcmp(opt->defname, "tablespace") == 0)
|
||||
tablespacename = defGetString(opt);
|
||||
else
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_SYNTAX_ERROR),
|
||||
@ -2500,6 +2503,30 @@ ExecReindex(ParseState *pstate, ReindexStmt *stmt, bool isTopLevel)
|
||||
(verbose ? REINDEXOPT_VERBOSE : 0) |
|
||||
(concurrently ? REINDEXOPT_CONCURRENTLY : 0);
|
||||
|
||||
/*
|
||||
* Assign the tablespace OID to move indexes to, with InvalidOid to do
|
||||
* nothing.
|
||||
*/
|
||||
if (tablespacename != NULL)
|
||||
{
|
||||
params.tablespaceOid = get_tablespace_oid(tablespacename, false);
|
||||
|
||||
/* Check permissions except when moving to database's default */
|
||||
if (OidIsValid(params.tablespaceOid) &&
|
||||
params.tablespaceOid != MyDatabaseTableSpace)
|
||||
{
|
||||
AclResult aclresult;
|
||||
|
||||
aclresult = pg_tablespace_aclcheck(params.tablespaceOid,
|
||||
GetUserId(), ACL_CREATE);
|
||||
if (aclresult != ACLCHECK_OK)
|
||||
aclcheck_error(aclresult, OBJECT_TABLESPACE,
|
||||
get_tablespace_name(params.tablespaceOid));
|
||||
}
|
||||
}
|
||||
else
|
||||
params.tablespaceOid = InvalidOid;
|
||||
|
||||
switch (stmt->kind)
|
||||
{
|
||||
case REINDEX_OBJECT_INDEX:
|
||||
@ -2730,6 +2757,7 @@ ReindexMultipleTables(const char *objectName, ReindexObjectType objectKind,
|
||||
List *relids = NIL;
|
||||
int num_keys;
|
||||
bool concurrent_warning = false;
|
||||
bool tablespace_warning = false;
|
||||
|
||||
AssertArg(objectName);
|
||||
Assert(objectKind == REINDEX_OBJECT_SCHEMA ||
|
||||
@ -2856,6 +2884,40 @@ ReindexMultipleTables(const char *objectName, ReindexObjectType objectKind,
|
||||
continue;
|
||||
}
|
||||
|
||||
/*
|
||||
* If a new tablespace is set, check if this relation has to be
|
||||
* skipped.
|
||||
*/
|
||||
if (OidIsValid(params->tablespaceOid))
|
||||
{
|
||||
bool skip_rel = false;
|
||||
|
||||
/*
|
||||
* Mapped relations cannot be moved to different tablespaces (in
|
||||
* particular this eliminates all shared catalogs.).
|
||||
*/
|
||||
if (RELKIND_HAS_STORAGE(classtuple->relkind) &&
|
||||
!OidIsValid(classtuple->relfilenode))
|
||||
skip_rel = true;
|
||||
|
||||
/*
|
||||
* A system relation is always skipped, even with
|
||||
* allow_system_table_mods enabled.
|
||||
*/
|
||||
if (IsSystemClass(relid, classtuple))
|
||||
skip_rel = true;
|
||||
|
||||
if (skip_rel)
|
||||
{
|
||||
if (!tablespace_warning)
|
||||
ereport(WARNING,
|
||||
(errcode(ERRCODE_INSUFFICIENT_PRIVILEGE),
|
||||
errmsg("cannot move system relations, skipping all")));
|
||||
tablespace_warning = true;
|
||||
continue;
|
||||
}
|
||||
}
|
||||
|
||||
/* Save the list of relation OIDs in private context */
|
||||
old = MemoryContextSwitchTo(private_context);
|
||||
|
||||
@ -3032,6 +3094,24 @@ ReindexMultipleInternal(List *relids, ReindexParams *params)
|
||||
continue;
|
||||
}
|
||||
|
||||
/*
|
||||
* Check permissions except when moving to database's default if a new
|
||||
* tablespace is chosen. Note that this check also happens in
|
||||
* ExecReindex(), but we do an extra check here as this runs across
|
||||
* multiple transactions.
|
||||
*/
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
params->tablespaceOid != MyDatabaseTableSpace)
|
||||
{
|
||||
AclResult aclresult;
|
||||
|
||||
aclresult = pg_tablespace_aclcheck(params->tablespaceOid,
|
||||
GetUserId(), ACL_CREATE);
|
||||
if (aclresult != ACLCHECK_OK)
|
||||
aclcheck_error(aclresult, OBJECT_TABLESPACE,
|
||||
get_tablespace_name(params->tablespaceOid));
|
||||
}
|
||||
|
||||
relkind = get_rel_relkind(relid);
|
||||
relpersistence = get_rel_persistence(relid);
|
||||
|
||||
@ -3210,6 +3290,13 @@ ReindexRelationConcurrently(Oid relationOid, ReindexParams *params)
|
||||
heapRelation = table_open(relationOid,
|
||||
ShareUpdateExclusiveLock);
|
||||
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
IsSystemRelation(heapRelation))
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot move system relation \"%s\"",
|
||||
RelationGetRelationName(heapRelation))));
|
||||
|
||||
/* Add all the valid indexes of relation to list */
|
||||
foreach(lc, RelationGetIndexList(heapRelation))
|
||||
{
|
||||
@ -3346,6 +3433,14 @@ ReindexRelationConcurrently(Oid relationOid, ReindexParams *params)
|
||||
else
|
||||
heapRelation = table_open(heapId,
|
||||
ShareUpdateExclusiveLock);
|
||||
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
IsSystemRelation(heapRelation))
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot move system relation \"%s\"",
|
||||
get_rel_name(relationOid))));
|
||||
|
||||
table_close(heapRelation, NoLock);
|
||||
|
||||
/* Save the list of relation OIDs in private context */
|
||||
@ -3390,6 +3485,13 @@ ReindexRelationConcurrently(Oid relationOid, ReindexParams *params)
|
||||
return false;
|
||||
}
|
||||
|
||||
/* It's not a shared catalog, so refuse to move it to shared tablespace */
|
||||
if (params->tablespaceOid == GLOBALTABLESPACE_OID)
|
||||
ereport(ERROR,
|
||||
(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
|
||||
errmsg("cannot move non-shared relation to tablespace \"%s\"",
|
||||
get_tablespace_name(params->tablespaceOid))));
|
||||
|
||||
Assert(heapRelationIds != NIL);
|
||||
|
||||
/*-----
|
||||
@ -3427,6 +3529,7 @@ ReindexRelationConcurrently(Oid relationOid, ReindexParams *params)
|
||||
Relation heapRel;
|
||||
Relation newIndexRel;
|
||||
LockRelId *lockrelid;
|
||||
Oid tablespaceid;
|
||||
|
||||
indexRel = index_open(idx->indexId, ShareUpdateExclusiveLock);
|
||||
heapRel = table_open(indexRel->rd_index->indrelid,
|
||||
@ -3458,9 +3561,17 @@ ReindexRelationConcurrently(Oid relationOid, ReindexParams *params)
|
||||
get_rel_namespace(indexRel->rd_index->indrelid),
|
||||
false);
|
||||
|
||||
/* Choose the new tablespace, indexes of toast tables are not moved */
|
||||
if (OidIsValid(params->tablespaceOid) &&
|
||||
heapRel->rd_rel->relkind != RELKIND_TOASTVALUE)
|
||||
tablespaceid = params->tablespaceOid;
|
||||
else
|
||||
tablespaceid = indexRel->rd_rel->reltablespace;
|
||||
|
||||
/* Create new index definition based on given index */
|
||||
newIndexId = index_concurrently_create_copy(heapRel,
|
||||
idx->indexId,
|
||||
tablespaceid,
|
||||
concurrentName);
|
||||
|
||||
/*
|
||||
|
@ -3641,7 +3641,9 @@ psql_completion(const char *text, int start, int end)
|
||||
* one word, so the above test is correct.
|
||||
*/
|
||||
if (ends_with(prev_wd, '(') || ends_with(prev_wd, ','))
|
||||
COMPLETE_WITH("CONCURRENTLY", "VERBOSE");
|
||||
COMPLETE_WITH("CONCURRENTLY", "TABLESPACE", "VERBOSE");
|
||||
else if (TailMatches("TABLESPACE"))
|
||||
COMPLETE_WITH_QUERY(Query_for_list_of_tablespaces);
|
||||
}
|
||||
|
||||
/* SECURITY LABEL */
|
||||
|
@ -33,6 +33,8 @@ typedef enum
|
||||
typedef struct ReindexParams
|
||||
{
|
||||
bits32 options; /* bitmask of REINDEXOPT_* */
|
||||
Oid tablespaceOid; /* New tablespace to move indexes to.
|
||||
* InvalidOid to do nothing. */
|
||||
} ReindexParams;
|
||||
|
||||
/* flag bits for ReindexParams->flags */
|
||||
@ -92,6 +94,7 @@ extern Oid index_create(Relation heapRelation,
|
||||
|
||||
extern Oid index_concurrently_create_copy(Relation heapRelation,
|
||||
Oid oldIndexId,
|
||||
Oid tablespaceOid,
|
||||
const char *newName);
|
||||
|
||||
extern void index_concurrently_build(Oid heapRelationId,
|
||||
|
@ -17,6 +17,127 @@ ALTER TABLESPACE regress_tblspace SET (some_nonexistent_parameter = true); -- f
|
||||
ALTER TABLESPACE regress_tblspace RESET (random_page_cost = 2.0); -- fail
|
||||
ALTER TABLESPACE regress_tblspace RESET (random_page_cost, effective_io_concurrency); -- ok
|
||||
|
||||
-- REINDEX (TABLESPACE)
|
||||
-- catalogs and system tablespaces
|
||||
-- system catalog, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_am;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_am;
|
||||
-- shared catalog, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_authid;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_authid;
|
||||
-- toast relations, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX pg_toast.pg_toast_1260_index;
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX CONCURRENTLY pg_toast.pg_toast_1260_index;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_toast.pg_toast_1260;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_toast.pg_toast_1260;
|
||||
-- system catalog, fail
|
||||
REINDEX (TABLESPACE pg_global) TABLE pg_authid;
|
||||
REINDEX (TABLESPACE pg_global) TABLE CONCURRENTLY pg_authid;
|
||||
|
||||
-- table with toast relation
|
||||
CREATE TABLE regress_tblspace_test_tbl (num1 bigint, num2 double precision, t text);
|
||||
INSERT INTO regress_tblspace_test_tbl (num1, num2, t)
|
||||
SELECT round(random()*100), random(), 'text'
|
||||
FROM generate_series(1, 10) s(i);
|
||||
CREATE INDEX regress_tblspace_test_tbl_idx ON regress_tblspace_test_tbl (num1);
|
||||
-- move to global tablespace, fail
|
||||
REINDEX (TABLESPACE pg_global) INDEX regress_tblspace_test_tbl_idx;
|
||||
REINDEX (TABLESPACE pg_global) INDEX CONCURRENTLY regress_tblspace_test_tbl_idx;
|
||||
|
||||
-- check transactional behavior of REINDEX (TABLESPACE)
|
||||
BEGIN;
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX regress_tblspace_test_tbl_idx;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE regress_tblspace_test_tbl;
|
||||
ROLLBACK;
|
||||
-- no relation moved to the new tablespace
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace';
|
||||
|
||||
-- check that all indexes are moved to a new tablespace with different
|
||||
-- relfilenode.
|
||||
-- Save first the existing relfilenode for the toast and main relations.
|
||||
SELECT relfilenode as main_filenode FROM pg_class
|
||||
WHERE relname = 'regress_tblspace_test_tbl_idx' \gset
|
||||
SELECT relfilenode as toast_filenode FROM pg_class
|
||||
WHERE oid =
|
||||
(SELECT i.indexrelid
|
||||
FROM pg_class c,
|
||||
pg_index i
|
||||
WHERE i.indrelid = c.reltoastrelid AND
|
||||
c.relname = 'regress_tblspace_test_tbl') \gset
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE regress_tblspace_test_tbl;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
ALTER TABLE regress_tblspace_test_tbl SET TABLESPACE regress_tblspace;
|
||||
ALTER TABLE regress_tblspace_test_tbl SET TABLESPACE pg_default;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
-- Move back to the default tablespace.
|
||||
ALTER INDEX regress_tblspace_test_tbl_idx SET TABLESPACE pg_default;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE regress_tblspace_test_tbl;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
SELECT relfilenode = :main_filenode AS main_same FROM pg_class
|
||||
WHERE relname = 'regress_tblspace_test_tbl_idx';
|
||||
SELECT relfilenode = :toast_filenode as toast_same FROM pg_class
|
||||
WHERE oid =
|
||||
(SELECT i.indexrelid
|
||||
FROM pg_class c,
|
||||
pg_index i
|
||||
WHERE i.indrelid = c.reltoastrelid AND
|
||||
c.relname = 'regress_tblspace_test_tbl');
|
||||
DROP TABLE regress_tblspace_test_tbl;
|
||||
|
||||
-- REINDEX (TABLESPACE) with partitions
|
||||
-- Create a partition tree and check the set of relations reindexed
|
||||
-- with their new tablespace.
|
||||
CREATE TABLE tbspace_reindex_part (c1 int, c2 int) PARTITION BY RANGE (c1);
|
||||
CREATE TABLE tbspace_reindex_part_0 PARTITION OF tbspace_reindex_part
|
||||
FOR VALUES FROM (0) TO (10) PARTITION BY list (c2);
|
||||
CREATE TABLE tbspace_reindex_part_0_1 PARTITION OF tbspace_reindex_part_0
|
||||
FOR VALUES IN (1);
|
||||
CREATE TABLE tbspace_reindex_part_0_2 PARTITION OF tbspace_reindex_part_0
|
||||
FOR VALUES IN (2);
|
||||
-- This partitioned table will have no partitions.
|
||||
CREATE TABLE tbspace_reindex_part_10 PARTITION OF tbspace_reindex_part
|
||||
FOR VALUES FROM (10) TO (20) PARTITION BY list (c2);
|
||||
-- Create some partitioned indexes
|
||||
CREATE INDEX tbspace_reindex_part_index ON ONLY tbspace_reindex_part (c1);
|
||||
CREATE INDEX tbspace_reindex_part_index_0 ON ONLY tbspace_reindex_part_0 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index ATTACH PARTITION tbspace_reindex_part_index_0;
|
||||
-- This partitioned index will have no partitions.
|
||||
CREATE INDEX tbspace_reindex_part_index_10 ON ONLY tbspace_reindex_part_10 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index ATTACH PARTITION tbspace_reindex_part_index_10;
|
||||
CREATE INDEX tbspace_reindex_part_index_0_1 ON ONLY tbspace_reindex_part_0_1 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index_0 ATTACH PARTITION tbspace_reindex_part_index_0_1;
|
||||
CREATE INDEX tbspace_reindex_part_index_0_2 ON ONLY tbspace_reindex_part_0_2 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index_0 ATTACH PARTITION tbspace_reindex_part_index_0_2;
|
||||
SELECT relid, parentrelid, level FROM pg_partition_tree('tbspace_reindex_part_index')
|
||||
ORDER BY relid, level;
|
||||
-- Track the original tablespace, relfilenode and OID of each index
|
||||
-- in the tree.
|
||||
CREATE TEMP TABLE reindex_temp_before AS
|
||||
SELECT oid, relname, relfilenode, reltablespace
|
||||
FROM pg_class
|
||||
WHERE relname ~ 'tbspace_reindex_part_index';
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tbspace_reindex_part;
|
||||
-- REINDEX CONCURRENTLY changes the OID of the old relation, hence a check
|
||||
-- based on the relation name below.
|
||||
SELECT b.relname,
|
||||
CASE WHEN a.relfilenode = b.relfilenode THEN 'relfilenode is unchanged'
|
||||
ELSE 'relfilenode has changed' END AS filenode,
|
||||
CASE WHEN a.reltablespace = b.reltablespace THEN 'reltablespace is unchanged'
|
||||
ELSE 'reltablespace has changed' END AS tbspace
|
||||
FROM reindex_temp_before b JOIN pg_class a ON b.relname = a.relname
|
||||
ORDER BY 1;
|
||||
DROP TABLE tbspace_reindex_part;
|
||||
|
||||
-- create a schema we can use
|
||||
CREATE SCHEMA testschema;
|
||||
|
||||
@ -269,6 +390,8 @@ 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;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tablespace_table; -- fail
|
||||
RESET ROLE;
|
||||
|
||||
ALTER TABLESPACE regress_tblspace RENAME TO regress_tblspace_renamed;
|
||||
|
@ -20,6 +20,185 @@ ERROR: unrecognized parameter "some_nonexistent_parameter"
|
||||
ALTER TABLESPACE regress_tblspace RESET (random_page_cost = 2.0); -- fail
|
||||
ERROR: RESET must not include values for parameters
|
||||
ALTER TABLESPACE regress_tblspace RESET (random_page_cost, effective_io_concurrency); -- ok
|
||||
-- REINDEX (TABLESPACE)
|
||||
-- catalogs and system tablespaces
|
||||
-- system catalog, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_am;
|
||||
ERROR: cannot move system relation "pg_am_name_index"
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_am;
|
||||
ERROR: cannot reindex system catalogs concurrently
|
||||
-- shared catalog, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_authid;
|
||||
ERROR: cannot move system relation "pg_authid_rolname_index"
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_authid;
|
||||
ERROR: cannot reindex system catalogs concurrently
|
||||
-- toast relations, fail
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX pg_toast.pg_toast_1260_index;
|
||||
ERROR: cannot move system relation "pg_toast_1260_index"
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX CONCURRENTLY pg_toast.pg_toast_1260_index;
|
||||
ERROR: cannot reindex system catalogs concurrently
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE pg_toast.pg_toast_1260;
|
||||
ERROR: cannot move system relation "pg_toast_1260_index"
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE CONCURRENTLY pg_toast.pg_toast_1260;
|
||||
ERROR: cannot reindex system catalogs concurrently
|
||||
-- system catalog, fail
|
||||
REINDEX (TABLESPACE pg_global) TABLE pg_authid;
|
||||
ERROR: cannot move system relation "pg_authid_rolname_index"
|
||||
REINDEX (TABLESPACE pg_global) TABLE CONCURRENTLY pg_authid;
|
||||
ERROR: cannot reindex system catalogs concurrently
|
||||
-- table with toast relation
|
||||
CREATE TABLE regress_tblspace_test_tbl (num1 bigint, num2 double precision, t text);
|
||||
INSERT INTO regress_tblspace_test_tbl (num1, num2, t)
|
||||
SELECT round(random()*100), random(), 'text'
|
||||
FROM generate_series(1, 10) s(i);
|
||||
CREATE INDEX regress_tblspace_test_tbl_idx ON regress_tblspace_test_tbl (num1);
|
||||
-- move to global tablespace, fail
|
||||
REINDEX (TABLESPACE pg_global) INDEX regress_tblspace_test_tbl_idx;
|
||||
ERROR: only shared relations can be placed in pg_global tablespace
|
||||
REINDEX (TABLESPACE pg_global) INDEX CONCURRENTLY regress_tblspace_test_tbl_idx;
|
||||
ERROR: cannot move non-shared relation to tablespace "pg_global"
|
||||
-- check transactional behavior of REINDEX (TABLESPACE)
|
||||
BEGIN;
|
||||
REINDEX (TABLESPACE regress_tblspace) INDEX regress_tblspace_test_tbl_idx;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE regress_tblspace_test_tbl;
|
||||
ROLLBACK;
|
||||
-- no relation moved to the new tablespace
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace';
|
||||
relname
|
||||
---------
|
||||
(0 rows)
|
||||
|
||||
-- check that all indexes are moved to a new tablespace with different
|
||||
-- relfilenode.
|
||||
-- Save first the existing relfilenode for the toast and main relations.
|
||||
SELECT relfilenode as main_filenode FROM pg_class
|
||||
WHERE relname = 'regress_tblspace_test_tbl_idx' \gset
|
||||
SELECT relfilenode as toast_filenode FROM pg_class
|
||||
WHERE oid =
|
||||
(SELECT i.indexrelid
|
||||
FROM pg_class c,
|
||||
pg_index i
|
||||
WHERE i.indrelid = c.reltoastrelid AND
|
||||
c.relname = 'regress_tblspace_test_tbl') \gset
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE regress_tblspace_test_tbl;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
relname
|
||||
-------------------------------
|
||||
regress_tblspace_test_tbl_idx
|
||||
(1 row)
|
||||
|
||||
ALTER TABLE regress_tblspace_test_tbl SET TABLESPACE regress_tblspace;
|
||||
ALTER TABLE regress_tblspace_test_tbl SET TABLESPACE pg_default;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
relname
|
||||
-------------------------------
|
||||
regress_tblspace_test_tbl_idx
|
||||
(1 row)
|
||||
|
||||
-- Move back to the default tablespace.
|
||||
ALTER INDEX regress_tblspace_test_tbl_idx SET TABLESPACE pg_default;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
relname
|
||||
---------
|
||||
(0 rows)
|
||||
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE regress_tblspace_test_tbl;
|
||||
SELECT c.relname FROM pg_class c, pg_tablespace s
|
||||
WHERE c.reltablespace = s.oid AND s.spcname = 'regress_tblspace'
|
||||
ORDER BY c.relname;
|
||||
relname
|
||||
-------------------------------
|
||||
regress_tblspace_test_tbl_idx
|
||||
(1 row)
|
||||
|
||||
SELECT relfilenode = :main_filenode AS main_same FROM pg_class
|
||||
WHERE relname = 'regress_tblspace_test_tbl_idx';
|
||||
main_same
|
||||
-----------
|
||||
f
|
||||
(1 row)
|
||||
|
||||
SELECT relfilenode = :toast_filenode as toast_same FROM pg_class
|
||||
WHERE oid =
|
||||
(SELECT i.indexrelid
|
||||
FROM pg_class c,
|
||||
pg_index i
|
||||
WHERE i.indrelid = c.reltoastrelid AND
|
||||
c.relname = 'regress_tblspace_test_tbl');
|
||||
toast_same
|
||||
------------
|
||||
f
|
||||
(1 row)
|
||||
|
||||
DROP TABLE regress_tblspace_test_tbl;
|
||||
-- REINDEX (TABLESPACE) with partitions
|
||||
-- Create a partition tree and check the set of relations reindexed
|
||||
-- with their new tablespace.
|
||||
CREATE TABLE tbspace_reindex_part (c1 int, c2 int) PARTITION BY RANGE (c1);
|
||||
CREATE TABLE tbspace_reindex_part_0 PARTITION OF tbspace_reindex_part
|
||||
FOR VALUES FROM (0) TO (10) PARTITION BY list (c2);
|
||||
CREATE TABLE tbspace_reindex_part_0_1 PARTITION OF tbspace_reindex_part_0
|
||||
FOR VALUES IN (1);
|
||||
CREATE TABLE tbspace_reindex_part_0_2 PARTITION OF tbspace_reindex_part_0
|
||||
FOR VALUES IN (2);
|
||||
-- This partitioned table will have no partitions.
|
||||
CREATE TABLE tbspace_reindex_part_10 PARTITION OF tbspace_reindex_part
|
||||
FOR VALUES FROM (10) TO (20) PARTITION BY list (c2);
|
||||
-- Create some partitioned indexes
|
||||
CREATE INDEX tbspace_reindex_part_index ON ONLY tbspace_reindex_part (c1);
|
||||
CREATE INDEX tbspace_reindex_part_index_0 ON ONLY tbspace_reindex_part_0 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index ATTACH PARTITION tbspace_reindex_part_index_0;
|
||||
-- This partitioned index will have no partitions.
|
||||
CREATE INDEX tbspace_reindex_part_index_10 ON ONLY tbspace_reindex_part_10 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index ATTACH PARTITION tbspace_reindex_part_index_10;
|
||||
CREATE INDEX tbspace_reindex_part_index_0_1 ON ONLY tbspace_reindex_part_0_1 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index_0 ATTACH PARTITION tbspace_reindex_part_index_0_1;
|
||||
CREATE INDEX tbspace_reindex_part_index_0_2 ON ONLY tbspace_reindex_part_0_2 (c1);
|
||||
ALTER INDEX tbspace_reindex_part_index_0 ATTACH PARTITION tbspace_reindex_part_index_0_2;
|
||||
SELECT relid, parentrelid, level FROM pg_partition_tree('tbspace_reindex_part_index')
|
||||
ORDER BY relid, level;
|
||||
relid | parentrelid | level
|
||||
--------------------------------+------------------------------+-------
|
||||
tbspace_reindex_part_index | | 0
|
||||
tbspace_reindex_part_index_0 | tbspace_reindex_part_index | 1
|
||||
tbspace_reindex_part_index_10 | tbspace_reindex_part_index | 1
|
||||
tbspace_reindex_part_index_0_1 | tbspace_reindex_part_index_0 | 2
|
||||
tbspace_reindex_part_index_0_2 | tbspace_reindex_part_index_0 | 2
|
||||
(5 rows)
|
||||
|
||||
-- Track the original tablespace, relfilenode and OID of each index
|
||||
-- in the tree.
|
||||
CREATE TEMP TABLE reindex_temp_before AS
|
||||
SELECT oid, relname, relfilenode, reltablespace
|
||||
FROM pg_class
|
||||
WHERE relname ~ 'tbspace_reindex_part_index';
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tbspace_reindex_part;
|
||||
-- REINDEX CONCURRENTLY changes the OID of the old relation, hence a check
|
||||
-- based on the relation name below.
|
||||
SELECT b.relname,
|
||||
CASE WHEN a.relfilenode = b.relfilenode THEN 'relfilenode is unchanged'
|
||||
ELSE 'relfilenode has changed' END AS filenode,
|
||||
CASE WHEN a.reltablespace = b.reltablespace THEN 'reltablespace is unchanged'
|
||||
ELSE 'reltablespace has changed' END AS tbspace
|
||||
FROM reindex_temp_before b JOIN pg_class a ON b.relname = a.relname
|
||||
ORDER BY 1;
|
||||
relname | filenode | tbspace
|
||||
--------------------------------+--------------------------+----------------------------
|
||||
tbspace_reindex_part_index | relfilenode is unchanged | reltablespace is unchanged
|
||||
tbspace_reindex_part_index_0 | relfilenode is unchanged | reltablespace is unchanged
|
||||
tbspace_reindex_part_index_0_1 | relfilenode has changed | reltablespace has changed
|
||||
tbspace_reindex_part_index_0_2 | relfilenode has changed | reltablespace has changed
|
||||
tbspace_reindex_part_index_10 | relfilenode is unchanged | reltablespace is unchanged
|
||||
(5 rows)
|
||||
|
||||
DROP TABLE tbspace_reindex_part;
|
||||
-- create a schema we can use
|
||||
CREATE SCHEMA testschema;
|
||||
-- try a table
|
||||
@ -732,6 +911,10 @@ SET SESSION ROLE regress_tablespace_user2;
|
||||
CREATE TABLE tablespace_table (i int) TABLESPACE regress_tblspace; -- fail
|
||||
ERROR: permission denied for tablespace regress_tblspace
|
||||
ALTER TABLE testschema.tablespace_acl ALTER c TYPE bigint;
|
||||
REINDEX (TABLESPACE regress_tblspace) TABLE tablespace_table; -- fail
|
||||
ERROR: permission denied for tablespace regress_tblspace
|
||||
REINDEX (TABLESPACE regress_tblspace, CONCURRENTLY) TABLE tablespace_table; -- fail
|
||||
ERROR: permission denied for tablespace regress_tblspace
|
||||
RESET ROLE;
|
||||
ALTER TABLESPACE regress_tblspace RENAME TO regress_tblspace_renamed;
|
||||
ALTER TABLE ALL IN TABLESPACE regress_tblspace_renamed SET TABLESPACE pg_default;
|
||||
|
Loading…
x
Reference in New Issue
Block a user