Commit 7dc40a2b authored by Bruce Momjian's avatar Bruce Momjian

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>)
parent 181ca96e
<!--
$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>
......
This diff is collapsed.
--
-- 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;
--
-- 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;
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