Major improvement in CLUSTER which preserves table characteristics using

relfilenode.

I sent the CLUSTER patch a few days ago and I think it was missed.  I
append it again, this time including the regression test files.  For the
committer, please note that you have to cvs add the files as they don't
exist.  Maybe add to the parallel and serial schedules also, but I don't
know such stuff.

Alvaro Herrera (<alvherre[a]atentus.com>)
This commit is contained in:
Bruce Momjian 2002-08-10 20:43:46 +00:00
parent 181ca96e7a
commit 7dc40a2be0
4 changed files with 561 additions and 85 deletions

View File

@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.16 2002/04/23 02:07:15 tgl Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/cluster.sgml,v 1.17 2002/08/10 20:43:46 momjian Exp $
PostgreSQL documentation
-->
@ -75,19 +75,6 @@ CLUSTER
</varlistentry>
<varlistentry>
<term><computeroutput>
ERROR: relation &lt;<replaceable class="PARAMETER">tablerelation_number</replaceable>&gt; inherits "<replaceable class="PARAMETER">table</replaceable>"
</computeroutput></term>
<listitem>
<para>
<comment>
This is not documented anywhere. It seems not to be possible to
cluster a table that is inherited.
</comment>
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
ERROR: Relation <replaceable class="PARAMETER">table</replaceable> does not exist!
</computeroutput></term>
<listitem>
@ -138,13 +125,6 @@ ERROR: Relation <replaceable class="PARAMETER">table</replaceable> does not exis
Notes
</title>
<para>
The table is actually copied to a temporary table in index
order, then renamed back to the original name. For this
reason, all grant permissions and other indexes are lost
when clustering is performed.
</para>
<para>
In cases where you are accessing single rows randomly
within a table, the actual order of the data in the heap
@ -194,6 +174,20 @@ SELECT <replaceable class="parameter">columnlist</replaceable> INTO TABLE <repla
fast because most of the heap data has already been
ordered, and the existing index is used.
</para>
<para>
During the cluster operation, a temporal table is created that contains
the table in the index order. Due to this, you need to have free space
on disk at least the size of the table itself, or the biggest index if
you have one that is larger than the table.
</para>
<para>
As opposed to previous releases, CLUSTER does not lose GRANT,
inheritance or foreign key information, and preserves indexes
other than the one being used for the CLUSTER.
</para>
</refsect2>
</refsect1>

View File

@ -15,7 +15,7 @@
*
*
* IDENTIFICATION
* $Header: /cvsroot/pgsql/src/backend/commands/cluster.c,v 1.83 2002/07/12 18:43:15 tgl Exp $
* $Header: /cvsroot/pgsql/src/backend/commands/cluster.c,v 1.84 2002/08/10 20:43:46 momjian Exp $
*
*-------------------------------------------------------------------------
*/
@ -27,45 +27,74 @@
#include "catalog/dependency.h"
#include "catalog/heap.h"
#include "catalog/index.h"
#include "catalog/indexing.h"
#include "catalog/catname.h"
#include "catalog/pg_index.h"
#include "catalog/pg_proc.h"
#include "commands/cluster.h"
#include "commands/tablecmds.h"
#include "miscadmin.h"
#include "utils/builtins.h"
#include "utils/fmgroids.h"
#include "utils/lsyscache.h"
#include "utils/syscache.h"
#include "utils/relcache.h"
/*
* We need one of these structs for each index in the relation to be
* clustered. It's basically the data needed by index_create() so
* we can recreate the indexes after destroying the old heap.
*/
typedef struct
{
char *indexName;
IndexInfo *indexInfo;
Oid accessMethodOID;
Oid *classOID;
Oid indexOID;
bool isPrimary;
} IndexAttrs;
static Oid copy_heap(Oid OIDOldHeap, const char *NewName);
static Oid copy_index(Oid OIDOldIndex, Oid OIDNewHeap,
const char *NewIndexName);
static void rebuildheap(Oid OIDNewHeap, Oid OIDOldHeap, Oid OIDOldIndex);
static List *get_indexattr_list (Oid OIDOldHeap);
static void recreate_indexattr(Oid OIDOldHeap, List *indexes);
static void swap_relfilenodes(Oid r1, Oid r2);
Relation RelationIdGetRelation(Oid relationId);
/*
* cluster
*
* STILL TO DO:
* Create a list of all the other indexes on this relation. Because
* the cluster will wreck all the tids, I'll need to destroy bogus
* indexes. The user will have to re-create them. Not nice, but
* I'm not a nice guy. The alternative is to try some kind of post
* destroy re-build. This may be possible. I'll check out what the
* index create functiond want in the way of paramaters. On the other
* hand, re-creating n indexes may blow out the space.
* This clusters the table by creating a new, clustered table and
* swapping the relfilenodes of the new table and the old table, so
* the OID of the original table is preserved. Thus we do not lose
* GRANT, inheritance nor references to this table (this was a bug
* in releases thru 7.3)
*
* Also create new indexes and swap the filenodes with the old indexes
* the same way we do for the relation.
*
* TODO:
* maybe we can get away with AccessShareLock for the table.
* Concurrency would be much improved. Only acquire
* AccessExclusiveLock right before swapping the filenodes.
* This would allow users to CLUSTER on a regular basis,
* practically eliminating the need for auto-clustered indexes.
*
* Preserve constraint bit for the indexes.
*/
void
cluster(RangeVar *oldrelation, char *oldindexname)
{
Oid OIDOldHeap,
OIDOldIndex,
OIDNewHeap,
OIDNewIndex;
OIDNewHeap;
Relation OldHeap,
OldIndex;
char NewHeapName[NAMEDATALEN];
char NewIndexName[NAMEDATALEN];
ObjectAddress object;
List *indexes;
/*
* We grab exclusive access to the target rel and index for the
@ -96,6 +125,9 @@ cluster(RangeVar *oldrelation, char *oldindexname)
heap_close(OldHeap, NoLock);
index_close(OldIndex);
/* Save the information of all indexes on the relation. */
indexes = get_indexattr_list(OIDOldHeap);
/*
* Create the new heap with a temporary name.
*/
@ -113,29 +145,27 @@ cluster(RangeVar *oldrelation, char *oldindexname)
/* To make the new heap's data visible. */
CommandCounterIncrement();
/* Create new index over the tuples of the new heap. */
snprintf(NewIndexName, NAMEDATALEN, "temp_%u", OIDOldIndex);
OIDNewIndex = copy_index(OIDOldIndex, OIDNewHeap, NewIndexName);
/* Swap the relfilenodes of the old and new heaps. */
swap_relfilenodes(OIDNewHeap, OIDOldHeap);
CommandCounterIncrement();
/* Destroy old heap (along with its index) and rename new. */
/* Destroy new heap with old filenode */
object.classId = RelOid_pg_class;
object.objectId = OIDOldHeap;
object.objectId = OIDNewHeap;
object.objectSubId = 0;
/* XXX better to use DROP_CASCADE here? */
/* The relation is local to our transaction and we know nothin
* depends on it, so DROP_RESTRICT should be OK.
*/
performDeletion(&object, DROP_RESTRICT);
/* performDeletion does CommandCounterIncrement at end */
renamerel(OIDNewHeap, oldrelation->relname);
/* This one might be unnecessary, but let's be safe. */
CommandCounterIncrement();
renamerel(OIDNewIndex, oldindexname);
/* Recreate the indexes on the relation. We do not need
* CommandCounterIncrement() because recreate_indexattr does it.
*/
recreate_indexattr(OIDOldHeap, indexes);
}
static Oid
@ -181,43 +211,6 @@ copy_heap(Oid OIDOldHeap, const char *NewName)
return OIDNewHeap;
}
static Oid
copy_index(Oid OIDOldIndex, Oid OIDNewHeap, const char *NewIndexName)
{
Oid OIDNewIndex;
Relation OldIndex,
NewHeap;
IndexInfo *indexInfo;
NewHeap = heap_open(OIDNewHeap, AccessExclusiveLock);
OldIndex = index_open(OIDOldIndex);
/*
* Create a new index like the old one. To do this I get the info
* from pg_index, and add a new index with a temporary name (that will
* be changed later).
*/
indexInfo = BuildIndexInfo(OldIndex->rd_index);
OIDNewIndex = index_create(OIDNewHeap,
NewIndexName,
indexInfo,
OldIndex->rd_rel->relam,
OldIndex->rd_index->indclass,
OldIndex->rd_index->indisprimary,
false, /* XXX losing constraint status */
allowSystemTableMods);
setRelhasindex(OIDNewHeap, true,
OldIndex->rd_index->indisprimary, InvalidOid);
index_close(OldIndex);
heap_close(NewHeap, NoLock);
return OIDNewIndex;
}
static void
rebuildheap(Oid OIDNewHeap, Oid OIDOldHeap, Oid OIDOldIndex)
{
@ -261,3 +254,188 @@ rebuildheap(Oid OIDNewHeap, Oid OIDOldHeap, Oid OIDOldIndex)
heap_close(LocalOldHeap, NoLock);
heap_close(LocalNewHeap, NoLock);
}
/* Get the necessary info about the indexes in the relation and
* return a List of IndexAttrs.
*/
List *
get_indexattr_list (Oid OIDOldHeap)
{
ScanKeyData entry;
HeapScanDesc scan;
Relation indexRelation;
HeapTuple indexTuple;
List *indexes = NIL;
IndexAttrs *attrs;
HeapTuple tuple;
Form_pg_index index;
/* Grab the index tuples by looking into RelationRelationName
* by the OID of the old heap.
*/
indexRelation = heap_openr(IndexRelationName, AccessShareLock);
ScanKeyEntryInitialize(&entry, 0, Anum_pg_index_indrelid,
F_OIDEQ, ObjectIdGetDatum(OIDOldHeap));
scan = heap_beginscan(indexRelation, SnapshotNow, 1, &entry);
while ((indexTuple = heap_getnext(scan, ForwardScanDirection)) != NULL)
{
index = (Form_pg_index) GETSTRUCT(indexTuple);
attrs = (IndexAttrs *) palloc(sizeof(IndexAttrs));
attrs->indexInfo = BuildIndexInfo(index);
attrs->isPrimary = index->indisprimary;
attrs->indexOID = index->indexrelid;
/* The opclasses are copied verbatim from the original indexes.
*/
attrs->classOID = (Oid *)palloc(sizeof(Oid) *
attrs->indexInfo->ii_NumIndexAttrs);
memcpy(attrs->classOID, index->indclass,
sizeof(Oid) * attrs->indexInfo->ii_NumIndexAttrs);
/* Name and access method of each index come from
* RelationRelationName.
*/
tuple = SearchSysCache(RELOID,
ObjectIdGetDatum(attrs->indexOID),
0, 0, 0);
if (!HeapTupleIsValid(tuple))
elog(ERROR, "CLUSTER: cannot find index %u", attrs->indexOID);
attrs->indexName = pstrdup(NameStr(((Form_pg_class) GETSTRUCT(tuple))->relname));
attrs->accessMethodOID = ((Form_pg_class) GETSTRUCT(tuple))->relam;
ReleaseSysCache(tuple);
/* Cons the gathered data into the list. We do not care about
* ordering, and this is more efficient than append.
*/
indexes=lcons((void *)attrs, indexes);
}
heap_endscan(scan);
heap_close(indexRelation, AccessShareLock);
return indexes;
}
/* Create new indexes and swap the filenodes with old indexes. Then drop
* the new index (carrying the old heap along).
*/
void
recreate_indexattr(Oid OIDOldHeap, List *indexes)
{
IndexAttrs *attrs;
List *elem;
Oid newIndexOID;
char newIndexName[NAMEDATALEN];
ObjectAddress object;
foreach (elem, indexes)
{
attrs=(IndexAttrs *) lfirst(elem);
/* Create the new index under a temporary name */
snprintf(newIndexName, NAMEDATALEN, "temp_%u", attrs->indexOID);
/* The new index will have constraint status set to false,
* but since we will only use its filenode it doesn't matter:
* after the filenode swap the index will keep the constraint
* status of the old index.
*/
newIndexOID = index_create(OIDOldHeap, newIndexName,
attrs->indexInfo, attrs->accessMethodOID,
attrs->classOID, attrs->isPrimary,
false, allowSystemTableMods);
CommandCounterIncrement();
/* Swap the filenodes. */
swap_relfilenodes(newIndexOID, attrs->indexOID);
setRelhasindex(OIDOldHeap, true, attrs->isPrimary, InvalidOid);
/* I'm not sure this one is needed, but let's be safe. */
CommandCounterIncrement();
/* Destroy new index with old filenode */
object.classId = RelOid_pg_class;
object.objectId = newIndexOID;
object.objectSubId = 0;
/* The relation is local to our transaction and we know
* nothing depends on it, so DROP_RESTRICT should be OK.
*/
performDeletion(&object, DROP_RESTRICT);
/* performDeletion does CommandCounterIncrement() at its end */
pfree(attrs->classOID);
pfree(attrs);
}
freeList(indexes);
}
/* Swap the relfilenodes for two given relations.
*/
void
swap_relfilenodes(Oid r1, Oid r2)
{
/* I can probably keep RelationRelationName open in the main
* function and pass the Relation around so I don't have to open
* it every time.
*/
Relation relRelation,
irels[Num_pg_class_indices],
rel;
HeapTuple reltup[2];
Oid tempRFNode;
int i;
/* We need both RelationRelationName tuples. */
relRelation = heap_openr(RelationRelationName, RowExclusiveLock);
reltup[0] = SearchSysCacheCopy(RELOID,
ObjectIdGetDatum(r1),
0, 0, 0);
if (!HeapTupleIsValid(reltup[0]))
elog(ERROR, "CLUSTER: Cannot find tuple for relation %u", r1);
reltup[1] = SearchSysCacheCopy(RELOID,
ObjectIdGetDatum(r2),
0, 0, 0);
if (!HeapTupleIsValid(reltup[1]))
elog(ERROR, "CLUSTER: Cannot find tuple for relation %u", r2);
/* The buffer manager gets confused if we swap relfilenodes for
* relations that are not both local or non-local to this transaction.
* Flush the buffers on both relations so the buffer manager can
* forget about'em.
*/
rel = RelationIdGetRelation(r1);
i = FlushRelationBuffers(rel, 0);
if (i < 0)
elog(ERROR, "CLUSTER: FlushRelationBuffers returned %d", i);
RelationClose(rel);
rel = RelationIdGetRelation(r1);
i = FlushRelationBuffers(rel, 0);
if (i < 0)
elog(ERROR, "CLUSTER: FlushRelationBuffers returned %d", i);
RelationClose(rel);
/* Actually swap the filenodes */
tempRFNode = ((Form_pg_class) GETSTRUCT(reltup[0]))->relfilenode;
((Form_pg_class) GETSTRUCT(reltup[0]))->relfilenode =
((Form_pg_class) GETSTRUCT(reltup[1]))->relfilenode;
((Form_pg_class) GETSTRUCT(reltup[1]))->relfilenode = tempRFNode;
/* Update the RelationRelationName tuples */
simple_heap_update(relRelation, &reltup[1]->t_self, reltup[1]);
simple_heap_update(relRelation, &reltup[0]->t_self, reltup[0]);
/* To keep system catalogs current. */
CatalogOpenIndices(Num_pg_class_indices, Name_pg_class_indices, irels);
CatalogIndexInsert(irels, Num_pg_class_indices, relRelation, reltup[1]);
CatalogIndexInsert(irels, Num_pg_class_indices, relRelation, reltup[0]);
CatalogCloseIndices(Num_pg_class_indices, irels);
CommandCounterIncrement();
heap_close(relRelation, NoLock);
heap_freetuple(reltup[0]);
heap_freetuple(reltup[1]);
}

View File

@ -0,0 +1,232 @@
--
-- CLUSTER
--
CREATE TABLE clstr_tst_s (rf_a SERIAL PRIMARY KEY,
b INT);
NOTICE: CREATE TABLE will create implicit sequence 'clstr_tst_s_rf_a_seq' for SERIAL column 'clstr_tst_s.rf_a'
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'clstr_tst_s_pkey' for table 'clstr_tst_s'
CREATE TABLE clstr_tst (a SERIAL PRIMARY KEY,
b INT,
c TEXT,
CONSTRAINT clstr_tst_con FOREIGN KEY (b) REFERENCES clstr_tst_s);
NOTICE: CREATE TABLE will create implicit sequence 'clstr_tst_a_seq' for SERIAL column 'clstr_tst.a'
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index 'clstr_tst_pkey' for table 'clstr_tst'
NOTICE: CREATE TABLE will create implicit trigger(s) for FOREIGN KEY check(s)
CREATE INDEX clstr_tst_b ON clstr_tst (b);
CREATE INDEX clstr_tst_c ON clstr_tst (c);
CREATE INDEX clstr_tst_c_b ON clstr_tst (c,b);
CREATE INDEX clstr_tst_b_c ON clstr_tst (b,c);
INSERT INTO clstr_tst_s (b) VALUES (0);
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
CREATE TABLE clstr_tst_inh () INHERITS (clstr_tst);
INSERT INTO clstr_tst (b, c) VALUES (11, 'once');
INSERT INTO clstr_tst (b, c) VALUES (10, 'diez');
INSERT INTO clstr_tst (b, c) VALUES (31, 'treinta y uno');
INSERT INTO clstr_tst (b, c) VALUES (22, 'veintidos');
INSERT INTO clstr_tst (b, c) VALUES (3, 'tres');
INSERT INTO clstr_tst (b, c) VALUES (20, 'veinte');
INSERT INTO clstr_tst (b, c) VALUES (23, 'veintitres');
INSERT INTO clstr_tst (b, c) VALUES (21, 'veintiuno');
INSERT INTO clstr_tst (b, c) VALUES (4, 'cuatro');
INSERT INTO clstr_tst (b, c) VALUES (14, 'catorce');
INSERT INTO clstr_tst (b, c) VALUES (2, 'dos');
INSERT INTO clstr_tst (b, c) VALUES (18, 'dieciocho');
INSERT INTO clstr_tst (b, c) VALUES (27, 'veintisiete');
INSERT INTO clstr_tst (b, c) VALUES (25, 'veinticinco');
INSERT INTO clstr_tst (b, c) VALUES (13, 'trece');
INSERT INTO clstr_tst (b, c) VALUES (28, 'veintiocho');
INSERT INTO clstr_tst (b, c) VALUES (32, 'treinta y dos');
INSERT INTO clstr_tst (b, c) VALUES (5, 'cinco');
INSERT INTO clstr_tst (b, c) VALUES (29, 'veintinueve');
INSERT INTO clstr_tst (b, c) VALUES (1, 'uno');
INSERT INTO clstr_tst (b, c) VALUES (24, 'veinticuatro');
INSERT INTO clstr_tst (b, c) VALUES (30, 'treinta');
INSERT INTO clstr_tst (b, c) VALUES (12, 'doce');
INSERT INTO clstr_tst (b, c) VALUES (17, 'diecisiete');
INSERT INTO clstr_tst (b, c) VALUES (9, 'nueve');
INSERT INTO clstr_tst (b, c) VALUES (19, 'diecinueve');
INSERT INTO clstr_tst (b, c) VALUES (26, 'veintiseis');
INSERT INTO clstr_tst (b, c) VALUES (15, 'quince');
INSERT INTO clstr_tst (b, c) VALUES (7, 'siete');
INSERT INTO clstr_tst (b, c) VALUES (16, 'dieciseis');
INSERT INTO clstr_tst (b, c) VALUES (8, 'ocho');
INSERT INTO clstr_tst (b, c) VALUES (6, 'seis');
CLUSTER clstr_tst_c ON clstr_tst;
SELECT * from clstr_tst;
a | b | c
----+----+---------------
10 | 14 | catorce
18 | 5 | cinco
9 | 4 | cuatro
26 | 19 | diecinueve
12 | 18 | dieciocho
30 | 16 | dieciseis
24 | 17 | diecisiete
2 | 10 | diez
23 | 12 | doce
11 | 2 | dos
25 | 9 | nueve
31 | 8 | ocho
1 | 11 | once
28 | 15 | quince
32 | 6 | seis
29 | 7 | siete
15 | 13 | trece
22 | 30 | treinta
17 | 32 | treinta y dos
3 | 31 | treinta y uno
5 | 3 | tres
20 | 1 | uno
6 | 20 | veinte
14 | 25 | veinticinco
21 | 24 | veinticuatro
4 | 22 | veintidos
19 | 29 | veintinueve
16 | 28 | veintiocho
27 | 26 | veintiseis
13 | 27 | veintisiete
7 | 23 | veintitres
8 | 21 | veintiuno
(32 rows)
SELECT * from clstr_tst ORDER BY a;
a | b | c
----+----+---------------
1 | 11 | once
2 | 10 | diez
3 | 31 | treinta y uno
4 | 22 | veintidos
5 | 3 | tres
6 | 20 | veinte
7 | 23 | veintitres
8 | 21 | veintiuno
9 | 4 | cuatro
10 | 14 | catorce
11 | 2 | dos
12 | 18 | dieciocho
13 | 27 | veintisiete
14 | 25 | veinticinco
15 | 13 | trece
16 | 28 | veintiocho
17 | 32 | treinta y dos
18 | 5 | cinco
19 | 29 | veintinueve
20 | 1 | uno
21 | 24 | veinticuatro
22 | 30 | treinta
23 | 12 | doce
24 | 17 | diecisiete
25 | 9 | nueve
26 | 19 | diecinueve
27 | 26 | veintiseis
28 | 15 | quince
29 | 7 | siete
30 | 16 | dieciseis
31 | 8 | ocho
32 | 6 | seis
(32 rows)
SELECT * from clstr_tst ORDER BY b;
a | b | c
----+----+---------------
20 | 1 | uno
11 | 2 | dos
5 | 3 | tres
9 | 4 | cuatro
18 | 5 | cinco
32 | 6 | seis
29 | 7 | siete
31 | 8 | ocho
25 | 9 | nueve
2 | 10 | diez
1 | 11 | once
23 | 12 | doce
15 | 13 | trece
10 | 14 | catorce
28 | 15 | quince
30 | 16 | dieciseis
24 | 17 | diecisiete
12 | 18 | dieciocho
26 | 19 | diecinueve
6 | 20 | veinte
8 | 21 | veintiuno
4 | 22 | veintidos
7 | 23 | veintitres
21 | 24 | veinticuatro
14 | 25 | veinticinco
27 | 26 | veintiseis
13 | 27 | veintisiete
16 | 28 | veintiocho
19 | 29 | veintinueve
22 | 30 | treinta
3 | 31 | treinta y uno
17 | 32 | treinta y dos
(32 rows)
SELECT * from clstr_tst ORDER BY c;
a | b | c
----+----+---------------
10 | 14 | catorce
18 | 5 | cinco
9 | 4 | cuatro
26 | 19 | diecinueve
12 | 18 | dieciocho
30 | 16 | dieciseis
24 | 17 | diecisiete
2 | 10 | diez
23 | 12 | doce
11 | 2 | dos
25 | 9 | nueve
31 | 8 | ocho
1 | 11 | once
28 | 15 | quince
32 | 6 | seis
29 | 7 | siete
15 | 13 | trece
22 | 30 | treinta
17 | 32 | treinta y dos
3 | 31 | treinta y uno
5 | 3 | tres
20 | 1 | uno
6 | 20 | veinte
14 | 25 | veinticinco
21 | 24 | veinticuatro
4 | 22 | veintidos
19 | 29 | veintinueve
16 | 28 | veintiocho
27 | 26 | veintiseis
13 | 27 | veintisiete
7 | 23 | veintitres
8 | 21 | veintiuno
(32 rows)
SELECT conname FROM pg_constraint WHERE conrelid=(SELECT oid FROM pg_class
WHERE relname='clstr_tst');
conname
----------------
clstr_tst_pkey
clstr_tst_con
(2 rows)
SELECT relname FROM pg_class WHERE relname LIKE 'clstr_tst%' ORDER BY relname;
relname
----------------------
clstr_tst
clstr_tst_a_seq
clstr_tst_b
clstr_tst_b_c
clstr_tst_c
clstr_tst_c_b
clstr_tst_inh
clstr_tst_pkey
clstr_tst_s
clstr_tst_s_pkey
clstr_tst_s_rf_a_seq
(11 rows)
DROP TABLE clstr_tst_inh;
DROP TABLE clstr_tst;

View File

@ -0,0 +1,72 @@
--
-- CLUSTER
--
CREATE TABLE clstr_tst_s (rf_a SERIAL PRIMARY KEY,
b INT);
CREATE TABLE clstr_tst (a SERIAL PRIMARY KEY,
b INT,
c TEXT,
CONSTRAINT clstr_tst_con FOREIGN KEY (b) REFERENCES clstr_tst_s);
CREATE INDEX clstr_tst_b ON clstr_tst (b);
CREATE INDEX clstr_tst_c ON clstr_tst (c);
CREATE INDEX clstr_tst_c_b ON clstr_tst (c,b);
CREATE INDEX clstr_tst_b_c ON clstr_tst (b,c);
INSERT INTO clstr_tst_s (b) VALUES (0);
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
INSERT INTO clstr_tst_s (b) SELECT b FROM clstr_tst_s;
CREATE TABLE clstr_tst_inh () INHERITS (clstr_tst);
INSERT INTO clstr_tst (b, c) VALUES (11, 'once');
INSERT INTO clstr_tst (b, c) VALUES (10, 'diez');
INSERT INTO clstr_tst (b, c) VALUES (31, 'treinta y uno');
INSERT INTO clstr_tst (b, c) VALUES (22, 'veintidos');
INSERT INTO clstr_tst (b, c) VALUES (3, 'tres');
INSERT INTO clstr_tst (b, c) VALUES (20, 'veinte');
INSERT INTO clstr_tst (b, c) VALUES (23, 'veintitres');
INSERT INTO clstr_tst (b, c) VALUES (21, 'veintiuno');
INSERT INTO clstr_tst (b, c) VALUES (4, 'cuatro');
INSERT INTO clstr_tst (b, c) VALUES (14, 'catorce');
INSERT INTO clstr_tst (b, c) VALUES (2, 'dos');
INSERT INTO clstr_tst (b, c) VALUES (18, 'dieciocho');
INSERT INTO clstr_tst (b, c) VALUES (27, 'veintisiete');
INSERT INTO clstr_tst (b, c) VALUES (25, 'veinticinco');
INSERT INTO clstr_tst (b, c) VALUES (13, 'trece');
INSERT INTO clstr_tst (b, c) VALUES (28, 'veintiocho');
INSERT INTO clstr_tst (b, c) VALUES (32, 'treinta y dos');
INSERT INTO clstr_tst (b, c) VALUES (5, 'cinco');
INSERT INTO clstr_tst (b, c) VALUES (29, 'veintinueve');
INSERT INTO clstr_tst (b, c) VALUES (1, 'uno');
INSERT INTO clstr_tst (b, c) VALUES (24, 'veinticuatro');
INSERT INTO clstr_tst (b, c) VALUES (30, 'treinta');
INSERT INTO clstr_tst (b, c) VALUES (12, 'doce');
INSERT INTO clstr_tst (b, c) VALUES (17, 'diecisiete');
INSERT INTO clstr_tst (b, c) VALUES (9, 'nueve');
INSERT INTO clstr_tst (b, c) VALUES (19, 'diecinueve');
INSERT INTO clstr_tst (b, c) VALUES (26, 'veintiseis');
INSERT INTO clstr_tst (b, c) VALUES (15, 'quince');
INSERT INTO clstr_tst (b, c) VALUES (7, 'siete');
INSERT INTO clstr_tst (b, c) VALUES (16, 'dieciseis');
INSERT INTO clstr_tst (b, c) VALUES (8, 'ocho');
INSERT INTO clstr_tst (b, c) VALUES (6, 'seis');
CLUSTER clstr_tst_c ON clstr_tst;
SELECT * from clstr_tst;
SELECT * from clstr_tst ORDER BY a;
SELECT * from clstr_tst ORDER BY b;
SELECT * from clstr_tst ORDER BY c;
SELECT conname FROM pg_constraint WHERE conrelid=(SELECT oid FROM pg_class
WHERE relname='clstr_tst');
SELECT relname FROM pg_class WHERE relname LIKE 'clstr_tst%' ORDER BY relname;
DROP TABLE clstr_tst_inh;
DROP TABLE clstr_tst;