Commit 8bc717cb authored by Bruce Momjian's avatar Bruce Momjian

New version attached. The following is implemented:

- CLUSTER ALL clusters all the tables that have some index with
  indisclustered set and the calling user owns.
- CLUSTER tablename clusters the named table, using the index with
  indisclustered set.  If no index has the bit set, throws elog(ERROR).
- The multi-relation version (CLUSTER ALL) uses a multitransaction
  approach, similar to what VACUUM does.

Alvaro Herrera
parent 5b7eb4dd
<!-- <!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.20 2002/09/21 18:32:54 petere Exp $ $Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.21 2002/11/15 03:09:35 momjian Exp $
PostgreSQL documentation PostgreSQL documentation
--> -->
...@@ -22,6 +22,8 @@ PostgreSQL documentation ...@@ -22,6 +22,8 @@ PostgreSQL documentation
</refsynopsisdivinfo> </refsynopsisdivinfo>
<synopsis> <synopsis>
CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable> CLUSTER <replaceable class="PARAMETER">indexname</replaceable> ON <replaceable class="PARAMETER">tablename</replaceable>
CLUSTER <replaceable class="PARAMETER">tablename</replaceable>
CLUSTER ALL
</synopsis> </synopsis>
<refsect2 id="R2-SQL-CLUSTER-1"> <refsect2 id="R2-SQL-CLUSTER-1">
...@@ -104,6 +106,20 @@ CLUSTER ...@@ -104,6 +106,20 @@ CLUSTER
periodically re-cluster by issuing the command again. periodically re-cluster by issuing the command again.
</para> </para>
<para>
When a table is clustered, <productname>PostgreSQL</productname>
remembers on which index it was clustered. In calls to
<command>CLUSTER <replaceable class="parameter">tablename</replaceable></command>,
the table is clustered on the same index that it was clustered before.
</para>
<para>
In calls to <command>CLUSTER ALL</command>, all the tables in the database
that the calling user owns are clustered using the saved information. This
form of <command>CLUSTER</command> cannot be called from inside a
transaction or function.
</para>
<refsect2 id="R2-SQL-CLUSTER-3"> <refsect2 id="R2-SQL-CLUSTER-3">
<refsect2info> <refsect2info>
<date>1998-09-08</date> <date>1998-09-08</date>
...@@ -141,8 +157,15 @@ CLUSTER ...@@ -141,8 +157,15 @@ CLUSTER
</para> </para>
<para> <para>
CLUSTER preserves GRANT, inheritance, index, foreign key, and other <command>CLUSTER</command> preserves GRANT, inheritance, index, foreign
ancillary information about the table. key, and other ancillary information about the table.
</para>
<para>
Because <command>CLUSTER</command> remembers the clustering information,
one can cluster the tables one wants clustered manually the first time, and
setup a timed event similar to <command>VACUUM</command> so that the tables
are periodically and automatically clustered.
</para> </para>
<para> <para>
...@@ -192,6 +215,18 @@ SELECT <replaceable class="parameter">columnlist</replaceable> INTO TABLE <repla ...@@ -192,6 +215,18 @@ SELECT <replaceable class="parameter">columnlist</replaceable> INTO TABLE <repla
<programlisting> <programlisting>
CLUSTER emp_ind ON emp; CLUSTER emp_ind ON emp;
</programlisting> </programlisting>
<para>
Cluster the employees relation using the same index that was used before:
</para>
<programlisting>
CLUSTER emp;
</programlisting>
<para>
Cluster all the tables on the database that have previously been clustered:
</para>
<programlisting>
CLUSTER ALL;
</programlisting>
</refsect1> </refsect1>
<refsect1 id="R1-SQL-CLUSTER-3"> <refsect1 id="R1-SQL-CLUSTER-3">
......
This diff is collapsed.
...@@ -11,7 +11,7 @@ ...@@ -11,7 +11,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.378 2002/11/15 02:50:08 momjian Exp $ * $Header: /cvsroot/pgsql/src/backend/parser/gram.y,v 2.379 2002/11/15 03:09:35 momjian Exp $
* *
* HISTORY * HISTORY
* AUTHOR DATE MAJOR EVENT * AUTHOR DATE MAJOR EVENT
...@@ -3761,6 +3761,8 @@ CreateConversionStmt: ...@@ -3761,6 +3761,8 @@ CreateConversionStmt:
* *
* QUERY: * QUERY:
* cluster <index_name> on <qualified_name> * cluster <index_name> on <qualified_name>
* cluster <qualified_name>
* cluster ALL
* *
*****************************************************************************/ *****************************************************************************/
...@@ -3772,6 +3774,20 @@ ClusterStmt: ...@@ -3772,6 +3774,20 @@ ClusterStmt:
n->indexname = $2; n->indexname = $2;
$$ = (Node*)n; $$ = (Node*)n;
} }
| CLUSTER qualified_name
{
ClusterStmt *n = makeNode(ClusterStmt);
n->relation = $2;
n->indexname = NULL;
$$ = (Node*)n;
}
| CLUSTER ALL
{
ClusterStmt *n = makeNode(ClusterStmt);
n->relation = NULL;
n->indexname = NULL;
$$ = (Node*)n;
}
; ;
/***************************************************************************** /*****************************************************************************
......
...@@ -10,7 +10,7 @@ ...@@ -10,7 +10,7 @@
* *
* *
* IDENTIFICATION * IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.181 2002/11/13 00:44:09 momjian Exp $ * $Header: /cvsroot/pgsql/src/backend/tcop/utility.c,v 1.182 2002/11/15 03:09:38 momjian Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -186,7 +186,6 @@ ProcessUtility(Node *parsetree, ...@@ -186,7 +186,6 @@ ProcessUtility(Node *parsetree,
CommandDest dest, CommandDest dest,
char *completionTag) char *completionTag)
{ {
char *relname;
if (completionTag) if (completionTag)
completionTag[0] = '\0'; completionTag[0] = '\0';
...@@ -702,9 +701,7 @@ ProcessUtility(Node *parsetree, ...@@ -702,9 +701,7 @@ ProcessUtility(Node *parsetree,
{ {
ClusterStmt *stmt = (ClusterStmt *) parsetree; ClusterStmt *stmt = (ClusterStmt *) parsetree;
CheckOwnership(stmt->relation, true); cluster(stmt);
cluster(stmt->relation, stmt->indexname);
} }
break; break;
...@@ -833,8 +830,8 @@ ProcessUtility(Node *parsetree, ...@@ -833,8 +830,8 @@ ProcessUtility(Node *parsetree,
switch (stmt->reindexType) switch (stmt->reindexType)
{ {
char *relname;
case INDEX: case INDEX:
relname = (char *) stmt->relation->relname;
CheckOwnership(stmt->relation, false); CheckOwnership(stmt->relation, false);
ReindexIndex(stmt->relation, stmt->force); ReindexIndex(stmt->relation, stmt->force);
break; break;
......
...@@ -6,16 +6,17 @@ ...@@ -6,16 +6,17 @@
* Portions Copyright (c) 1996-2002, PostgreSQL Global Development Group * Portions Copyright (c) 1996-2002, PostgreSQL Global Development Group
* Portions Copyright (c) 1994-5, Regents of the University of California * Portions Copyright (c) 1994-5, Regents of the University of California
* *
* $Id: cluster.h,v 1.15 2002/08/10 21:00:34 momjian Exp $ * $Id: cluster.h,v 1.16 2002/11/15 03:09:39 momjian Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
#ifndef CLUSTER_H #ifndef CLUSTER_H
#define CLUSTER_H #define CLUSTER_H
#include <nodes/parsenodes.h>
/* /*
* functions * functions
*/ */
extern void cluster(RangeVar *oldrelation, char *oldindexname); extern void cluster(ClusterStmt *stmt);
#endif /* CLUSTER_H */ #endif /* CLUSTER_H */
...@@ -7,7 +7,7 @@ ...@@ -7,7 +7,7 @@
* Portions Copyright (c) 1996-2002, PostgreSQL Global Development Group * Portions Copyright (c) 1996-2002, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California * Portions Copyright (c) 1994, Regents of the University of California
* *
* $Id: parsenodes.h,v 1.214 2002/11/15 02:50:12 momjian Exp $ * $Id: parsenodes.h,v 1.215 2002/11/15 03:09:39 momjian Exp $
* *
*------------------------------------------------------------------------- *-------------------------------------------------------------------------
*/ */
...@@ -1533,7 +1533,7 @@ typedef struct DropdbStmt ...@@ -1533,7 +1533,7 @@ typedef struct DropdbStmt
typedef struct ClusterStmt typedef struct ClusterStmt
{ {
NodeTag type; NodeTag type;
RangeVar *relation; /* relation being indexed */ RangeVar *relation; /* relation being indexed, or NULL if all */
char *indexname; /* original index defined */ char *indexname; /* original index defined */
} ClusterStmt; } ClusterStmt;
......
...@@ -285,3 +285,67 @@ WHERE pg_class.oid=indexrelid ...@@ -285,3 +285,67 @@ WHERE pg_class.oid=indexrelid
clstr_tst_c clstr_tst_c
(1 row) (1 row)
-- Verify that clustering all tables does in fact cluster the right ones
CREATE USER clstr_user;
CREATE TABLE clstr_1 (a INT PRIMARY KEY);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'clstr_1_pkey' for table 'clstr_1'
CREATE TABLE clstr_2 (a INT PRIMARY KEY);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'clstr_2_pkey' for table 'clstr_2'
CREATE TABLE clstr_3 (a INT PRIMARY KEY);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'clstr_3_pkey' for table 'clstr_3'
ALTER TABLE clstr_1 OWNER TO clstr_user;
ALTER TABLE clstr_3 OWNER TO clstr_user;
GRANT SELECT ON clstr_2 TO clstr_user;
INSERT INTO clstr_1 VALUES (2);
INSERT INTO clstr_1 VALUES (1);
INSERT INTO clstr_2 VALUES (2);
INSERT INTO clstr_2 VALUES (1);
INSERT INTO clstr_3 VALUES (2);
INSERT INTO clstr_3 VALUES (1);
CLUSTER clstr_1_pkey ON clstr_1;
CLUSTER clstr_2_pkey ON clstr_2;
SELECT * FROM clstr_1 UNION ALL
SELECT * FROM clstr_2 UNION ALL
SELECT * FROM clstr_3;
a
---
1
2
1
2
2
1
(6 rows)
-- revert to the original state
DELETE FROM clstr_1;
DELETE FROM clstr_2;
DELETE FROM clstr_3;
INSERT INTO clstr_1 VALUES (2);
INSERT INTO clstr_1 VALUES (1);
INSERT INTO clstr_2 VALUES (2);
INSERT INTO clstr_2 VALUES (1);
INSERT INTO clstr_3 VALUES (2);
INSERT INTO clstr_3 VALUES (1);
-- this user can only cluster clstr_1 and clstr_3, but the latter
-- has not been clustered
SET SESSION AUTHORIZATION clstr_user;
CLUSTER ALL;
SELECT * FROM clstr_1 UNION ALL
SELECT * FROM clstr_2 UNION ALL
SELECT * FROM clstr_3;
a
---
1
2
2
1
2
1
(6 rows)
-- clean up
\c -
DROP TABLE clstr_1;
DROP TABLE clstr_3;
DROP USER clstr_user;
...@@ -86,3 +86,59 @@ WHERE pg_class.oid=indexrelid ...@@ -86,3 +86,59 @@ WHERE pg_class.oid=indexrelid
AND indrelid=pg_class_2.oid AND indrelid=pg_class_2.oid
AND pg_class_2.relname = 'clstr_tst' AND pg_class_2.relname = 'clstr_tst'
AND indisclustered; AND indisclustered;
-- Verify that clustering all tables does in fact cluster the right ones
CREATE USER clstr_user;
CREATE TABLE clstr_1 (a INT PRIMARY KEY);
CREATE TABLE clstr_2 (a INT PRIMARY KEY);
CREATE TABLE clstr_3 (a INT PRIMARY KEY);
ALTER TABLE clstr_1 OWNER TO clstr_user;
ALTER TABLE clstr_3 OWNER TO clstr_user;
GRANT SELECT ON clstr_2 TO clstr_user;
INSERT INTO clstr_1 VALUES (2);
INSERT INTO clstr_1 VALUES (1);
INSERT INTO clstr_2 VALUES (2);
INSERT INTO clstr_2 VALUES (1);
INSERT INTO clstr_3 VALUES (2);
INSERT INTO clstr_3 VALUES (1);
-- "CLUSTER <tablename>" on a table that hasn't been clustered
CLUSTER clstr_2;
CLUSTER clstr_1_pkey ON clstr_1;
CLUSTER clstr_2_pkey ON clstr_2;
SELECT * FROM clstr_1 UNION ALL
SELECT * FROM clstr_2 UNION ALL
SELECT * FROM clstr_3;
-- revert to the original state
DELETE FROM clstr_1;
DELETE FROM clstr_2;
DELETE FROM clstr_3;
INSERT INTO clstr_1 VALUES (2);
INSERT INTO clstr_1 VALUES (1);
INSERT INTO clstr_2 VALUES (2);
INSERT INTO clstr_2 VALUES (1);
INSERT INTO clstr_3 VALUES (2);
INSERT INTO clstr_3 VALUES (1);
-- this user can only cluster clstr_1 and clstr_3, but the latter
-- has not been clustered
SET SESSION AUTHORIZATION clstr_user;
CLUSTER ALL;
SELECT * FROM clstr_1 UNION ALL
SELECT * FROM clstr_2 UNION ALL
SELECT * FROM clstr_3;
-- cluster a single table using the indisclustered bit previously set
DELETE FROM clstr_1;
INSERT INTO clstr_1 VALUES (2);
INSERT INTO clstr_1 VALUES (1);
CLUSTER clstr_1;
SELECT * FROM clstr_1;
-- clean up
\c -
DROP TABLE clstr_1;
DROP TABLE clstr_3;
DROP USER clstr_user;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment