diff --git a/doc/src/sgml/ref/alter_index.sgml b/doc/src/sgml/ref/alter_index.sgml index d497dd47af..a38005bc20 100644 --- a/doc/src/sgml/ref/alter_index.sgml +++ b/doc/src/sgml/ref/alter_index.sgml @@ -1,5 +1,5 @@ @@ -22,8 +22,8 @@ PostgreSQL documentation ALTER INDEX name RENAME TO new_name ALTER INDEX name SET TABLESPACE tablespace_name -ALTER INDEX name SET (FILLFACTOR = fillfactor) -ALTER INDEX name RESET (FILLFACTOR) +ALTER INDEX name SET ( storage_parameter = value [, ... ] ) +ALTER INDEX name RESET ( storage_parameter [, ... ] ) @@ -59,21 +59,28 @@ ALTER INDEX name RESET (FILLFACTOR) - SET (FILLFACTOR) + SET ( storage_parameter = value [, ... ] ) - This form changes the index's fillfactor to the specified percentage. - Index structure is not modified immediately; use REINDEX - to ensure reflection of the change. + This form changes one or more index-method-specific storage parameters + for the index. See + + for details on the available parameters. Note that the index contents + will not be modified immediately by this command; depending on the + parameter you may need to rebuild the index with + + to get the desired effects. - RESET (FILLFACTOR) + RESET ( storage_parameter [, ... ] ) - This form changes the index's fillfactor to the default value. + This form resets one or more index-method-specific storage parameters to + their defaults. As with SET, a REINDEX + may be needed to update the index entirely. @@ -116,6 +123,25 @@ ALTER INDEX name RESET (FILLFACTOR) + + storage_parameter + + + The name of an index-method-specific storage parameter. + + + + + + value + + + The new value for an index-method-specific storage parameter. + This might be a number or a word depending on the parameter. + + + + @@ -154,6 +180,15 @@ ALTER INDEX distributors RENAME TO suppliers; To move an index to a different tablespace: ALTER INDEX distributors SET TABLESPACE fasttablespace; + + + + + To change an index's fill factor (assuming that the index method + supports it): + +ALTER INDEX distributors SET (fillfactor = 75); +REINDEX INDEX distributors; @@ -167,6 +202,16 @@ ALTER INDEX distributors SET TABLESPACE fasttablespace; extension. + + + + See Also + + + + + + @@ -46,8 +46,8 @@ where action is one of: CLUSTER ON index_name SET WITHOUT CLUSTER SET WITHOUT OIDS - SET (FILLFACTOR = fillfactor) - RESET (FILLFACTOR) + SET ( storage_parameter = value [, ... ] ) + RESET ( storage_parameter [, ... ] ) INHERIT parent_table NO INHERIT parent_table OWNER TO new_owner @@ -253,38 +253,70 @@ where action is one of: + + SET ( storage_parameter = value [, ... ] ) + + + This form changes one or more storage parameters for the table. See + + for details on the available parameters. Note that the table contents + will not be modified immediately by this command; depending on the + parameter you may need to rewrite the table to get the desired effects. + That can be done with or one of the forms of ALTER + TABLE that forces a table rewrite. + + + + + While CREATE TABLE allows OIDS to be specified + in the WITH (storage_parameter) syntax, + ALTER TABLE does not treat OIDS as a + storage parameter. + + + + + + + RESET ( storage_parameter [, ... ] ) + + + This form resets one or more storage parameters to their + defaults. As with SET, a table rewrite may be + needed to update the table entirely. + + + + INHERIT parent_table - This form adds a new parent table to the table. This won't add new columns to the child table, instead all columns of the parent table must already exist in the child table. They must have matching data types, and if they have NOT NULL constraints in the parent then they must also have NOT NULL constraints in the child. + - - - + There must also be matching table constraints for all CHECK table constraints of the parent. Currently UNIQUE, PRIMARY KEY, and FOREIGN KEY constraints are ignored however this may change in the future. + - - - + The easiest way to create a suitable table is to create a table using INHERITS and then remove it via NO INHERIT. Alternatively create a table using LIKE however note that LIKE does not create the necessary constraints. - - @@ -292,9 +324,9 @@ where action is one of: NO INHERIT parent_table - This form removes a parent table from the list of parents of the table. - Queries against the parent table will no longer include records drawn - from the target table. + This form removes a parent table from the list of parents of the table. + Queries against the parent table will no longer include records drawn + from the target table. @@ -323,26 +355,6 @@ where action is one of: - - SET (FILLFACTOR) - - - This form changes the table's fillfactor to the specified percentage. - Table structure is not modified immediately; use CLUSTER - to ensure reflection of the change. - - - - - - RESET - - - This form changes the table's fillfactor to the default value. - - - - RENAME @@ -524,6 +536,34 @@ where action is one of: + + storage_parameter + + + The name of a table storage parameter. + + + + + + value + + + The new value for a table storage parameter. + This might be a number or a word depending on the parameter. + + + + + + parent_table + + + A parent table to associate or de-associate with this table. + + + + new_owner diff --git a/doc/src/sgml/ref/create_index.sgml b/doc/src/sgml/ref/create_index.sgml index 787184a5e2..d3e9b1dc66 100644 --- a/doc/src/sgml/ref/create_index.sgml +++ b/doc/src/sgml/ref/create_index.sgml @@ -1,5 +1,5 @@ @@ -22,7 +22,7 @@ PostgreSQL documentation CREATE [ UNIQUE ] INDEX name ON table [ USING method ] ( { column | ( expression ) } [ opclass ] [, ...] ) - [ WITH (FILLFACTOR = fillfactor) ] + [ WITH ( storage_parameter = value [, ... ] ) ] [ TABLESPACE tablespace ] [ WHERE predicate ] @@ -56,7 +56,7 @@ CREATE [ UNIQUE ] INDEX name ON PostgreSQL provides the index methods - B-tree, hash, and GiST. Users can also define their own index + B-tree, hash, GiST, and GIN. Users can also define their own index methods, but that is fairly complicated. @@ -136,7 +136,7 @@ CREATE [ UNIQUE ] INDEX name ON The name of the index method to be used. Choices are btree, hash, - and gist. The + gist, and gin. The default method is btree. @@ -173,10 +173,11 @@ CREATE [ UNIQUE ] INDEX name ON - fillfactor + storage_parameter - The index's fillfactor in percentage. + The name of an index-method-specific storage parameter. See + below for details. @@ -203,6 +204,41 @@ CREATE [ UNIQUE ] INDEX name ON + + + Index Storage Parameters + + + The WITH clause can specify storage parameters + for indexes. Each index method can have its own set of allowed storage + parameters. The built-in index methods all accept a single parameter: + + + + + + FILLFACTOR + + + The fillfactor for an index is a percentage that determines how full + the index method will try to pack index pages. For B-trees, pages + are filled to this percentage during initial index build, and also + when extending the index at the right (largest key values). If pages + subsequently become completely full, they will be split, leading to + gradual degradation in the index's efficiency. B-trees use a default + fillfactor of 90, but any value from 70 to 100 can be selected. + If the table is static then fillfactor 100 is best to minimize the + index's physical size, but for heavily updated tables a smaller + fillfactor is better to minimize the need for page splits. The + other index methods use fillfactor in different but roughly analogous + ways; the default fillfactor and allowed range varies. + + + + + + + @@ -271,6 +307,21 @@ CREATE UNIQUE INDEX title_idx ON films (title); + + To create an index on the expression lower(title), + allowing efficient case-insensitive searches: + +CREATE INDEX lower_title_idx ON films ((lower(title))); + + + + + To create an index with non-default fill factor: + +CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70); + + + To create an index on the column code in the table films and have the index reside in the tablespace diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index c40c37c19c..24f78644d8 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -1,5 +1,5 @@ @@ -27,8 +27,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE storage_parameter [= value] [, ... ] ) | WITH OIDS | WITHOUT OIDS ] [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] [ TABLESPACE tablespace ] @@ -37,9 +36,9 @@ where column_constraint is: [ CONSTRAINT constraint_name ] { NOT NULL | NULL | - UNIQUE [ USING INDEX TABLESPACE tablespace ] | - PRIMARY KEY [ USING INDEX TABLESPACE tablespace ] | - CHECK (expression) | + UNIQUE index_parameters | + PRIMARY KEY index_parameters | + CHECK ( expression ) | REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE action ] [ ON UPDATE action ] } [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] @@ -47,12 +46,17 @@ where column_constraint is: and table_constraint is: [ CONSTRAINT constraint_name ] -{ UNIQUE ( column_name [, ... ] ) [ USING INDEX TABLESPACE tablespace ] | - PRIMARY KEY ( column_name [, ... ] ) [ USING INDEX TABLESPACE tablespace ] | +{ UNIQUE ( column_name [, ... ] ) index_parameters | + PRIMARY KEY ( column_name [, ... ] ) index_parameters | CHECK ( expression ) | FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] [ ON DELETE action ] [ ON UPDATE action ] } [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ] + +index_parameters in UNIQUE and PRIMARY KEY constraints are: + +[ WITH ( storage_parameter [= value] [, ... ] ) ] +[ USING INDEX TABLESPACE tablespace ] @@ -270,49 +274,6 @@ and table_constraint is: - - WITH OIDS - WITHOUT OIDS - - - This optional clause specifies whether rows of the new table - should have OIDs (object identifiers) assigned to them. If - neither WITH OIDS nor WITHOUT - OIDS is specified, the default value depends upon the - configuration parameter. (If - the new table inherits from any tables that have OIDs, then - WITH OIDS is forced even if the command says - WITHOUT OIDS.) - - - - If WITHOUT OIDS is specified or implied, the new - table does not store OIDs and no OID will be assigned for a row inserted - into it. This is generally considered worthwhile, since it - will reduce OID consumption and thereby postpone the wraparound - of the 32-bit OID counter. Once the counter wraps around, OIDs - can no longer be assumed to be unique, which makes them - considerably less useful. In addition, excluding OIDs from a - table reduces the space required to store the table on disk by - 4 bytes per row (on most machines), slightly improving performance. - - - - To remove OIDs from a table after it has been created, use . - - - - - - WITH (FILLFACTOR = fillfactor) - - - This optional clause specifies the table's fillfactor in percentage. - - - - CONSTRAINT constraint_name @@ -407,7 +368,7 @@ and table_constraint is: - CHECK (expression) + CHECK ( expression ) The CHECK clause specifies an expression producing a @@ -581,6 +542,57 @@ and table_constraint is: + + WITH ( storage_parameter [= value] [, ... ] ) + + + This clause specifies optional storage parameters for a table or index; + see for more + information. The WITH clause for a + table can also include OIDS=TRUE (or just OIDS) + to specify that rows of the new table + should have OIDs (object identifiers) assigned to them, or + OIDS=FALSE to specify that the rows should not have OIDs. + If OIDS is not specified, the default setting depends upon + the configuration parameter. + (If the new table inherits from any tables that have OIDs, then + OIDS=TRUE is forced even if the command says + OIDS=FALSE.) + + + + If OIDS=FALSE is specified or implied, the new + table does not store OIDs and no OID will be assigned for a row inserted + into it. This is generally considered worthwhile, since it + will reduce OID consumption and thereby postpone the wraparound + of the 32-bit OID counter. Once the counter wraps around, OIDs + can no longer be assumed to be unique, which makes them + considerably less useful. In addition, excluding OIDs from a + table reduces the space required to store the table on disk by + 4 bytes per row (on most machines), slightly improving performance. + + + + To remove OIDs from a table after it has been created, use . + + + + + + WITH OIDS + WITHOUT OIDS + + + These are obsolescent syntaxes equivalent to WITH (OIDS) + and WITH (OIDS=FALSE), respectively. If you wish to give + both an OIDS setting and storage parameters, you must use + the WITH ( ... ) syntax; see above. + + + + ON COMMIT @@ -656,6 +668,42 @@ and table_constraint is: + + + Storage Parameters + + + The WITH clause can specify storage parameters + for tables, and for indexes associated with a UNIQUE or + PRIMARY KEY constraint. Storage parameters for + indexes are documented in . The only storage parameter currently + available for tables is: + + + + + + FILLFACTOR + + + The fillfactor for a table is a percentage between 10 and 100. + 100 (complete packing) is the default. When a smaller fillfactor + is specified, INSERT operations pack table pages only + to the indicated percentage; the remaining space on each page is + reserved for updating rows on that page. This gives UPDATE + a chance to place the updated copy of a row on the same page as the + original, which is more efficient than placing it on a different page. + For a table whose entries are never updated, complete packing is the + best choice, but in heavily updated tables smaller fillfactors are + appropriate. + + + + + + + @@ -677,7 +725,7 @@ and table_constraint is: - The use of WITHOUT OIDS is not recommended + The use of OIDS=FALSE is not recommended for tables with no primary key, since without either an OID or a unique data key, it is difficult to identify specific rows. @@ -697,10 +745,10 @@ and table_constraint is: inheritance and unique constraints rather dysfunctional. - - A table cannot have more than 1600 columns. (In practice, the - effective limit is lower because of tuple-length constraints.) - + + A table cannot have more than 1600 columns. (In practice, the + effective limit is usually lower because of tuple-length constraints.) + @@ -784,8 +832,7 @@ CREATE TABLE distributors ( Define a primary key table constraint for the table - films. Primary key table constraints can be defined - on one or more columns of the table. + films: CREATE TABLE films ( @@ -804,7 +851,7 @@ CREATE TABLE films ( Define a primary key constraint for table distributors. The following two examples are equivalent, the first using the table constraint syntax, the second - the column constraint syntax. + the column constraint syntax: CREATE TABLE distributors ( @@ -823,12 +870,12 @@ CREATE TABLE distributors ( - This assigns a literal constant default value for the column - name, arranges for the default value of column + Assign a literal constant default value for the column + name, arrange for the default value of column did to be generated by selecting the next value - of a sequence object, and makes the default value of + of a sequence object, and make the default value of modtime be the time at which the row is - inserted. + inserted: CREATE TABLE distributors ( @@ -862,7 +909,7 @@ CREATE TABLE distributors ( ); - The above is equivalent to the following specified as a table constraint: + The same, specified as a table constraint: CREATE TABLE distributors ( @@ -873,6 +920,20 @@ CREATE TABLE distributors ( + + Create the same table, specifying 70% fill factor for both the table + and its unique index: + + +CREATE TABLE distributors ( + did integer, + name varchar(40), + UNIQUE(name) WITH (fillfactor=70) +) +WITH (fillfactor=70); + + + Create table cinemas in tablespace diskvol1: @@ -977,15 +1038,6 @@ CREATE TABLE cinemas ( - - Object IDs - - - The PostgreSQL concept of OIDs is not - standard. - - - Zero-column tables @@ -999,6 +1051,15 @@ CREATE TABLE cinemas ( + + <literal>WITH</> clause + + + The WITH clause is a PostgreSQL + extension; neither storage parameters nor OIDs are in the standard. + + + Tablespaces diff --git a/doc/src/sgml/ref/create_table_as.sgml b/doc/src/sgml/ref/create_table_as.sgml index 53fb6c0971..db9c3aa9de 100644 --- a/doc/src/sgml/ref/create_table_as.sgml +++ b/doc/src/sgml/ref/create_table_as.sgml @@ -1,5 +1,5 @@ @@ -22,8 +22,7 @@ PostgreSQL documentation CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name [ (column_name [, ...] ) ] - [ WITH OIDS | WITHOUT OIDS ] - [ WITH (FILLFACTOR = fillfactor) ] + [ WITH ( storage_parameter [= value] [, ... ] ) | WITH OIDS | WITHOUT OIDS ] [ ON COMMIT { PRESERVE ROWS | DELETE ROWS | DROP } ] [ TABLESPACE tablespace ] AS query @@ -104,24 +103,32 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name - WITH OIDS - WITHOUT OIDS - - - This optional clause specifies whether the table created by - CREATE TABLE AS should include OIDs. If - neither form of this clause is specified, the value of the - configuration parameter is - used. - - + WITH ( storage_parameter [= value] [, ... ] ) + + + This clause specifies optional storage parameters for the new table; + see for more + information. The WITH clause + can also include OIDS=TRUE (or just OIDS) + to specify that rows of the new table + should have OIDs (object identifiers) assigned to them, or + OIDS=FALSE to specify that the rows should not have OIDs. + See for more information. + + - WITH (FILLFACTOR = fillfactor) + WITH OIDS + WITHOUT OIDS - This optional clause specifies the table's fillfactor in percentage. + These are obsolescent syntaxes equivalent to WITH (OIDS) + and WITH (OIDS=FALSE), respectively. If you wish to give + both an OIDS setting and storage parameters, you must use + the WITH ( ... ) syntax; see above. @@ -225,7 +232,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name this variable is false by default, so the default behavior is not identical to pre-8.0 releases. Applications that require OIDs in the table created by CREATE TABLE - AS should explicitly specify WITH OIDS + AS should explicitly specify WITH (OIDS) to ensure proper behavior. @@ -244,15 +251,14 @@ CREATE TABLE films_recent AS - Create a new temporary table that will be dropped at commit - films_recent with oids consisting of only - recent entries from the table films using a - prepared statement: + Create a new temporary table films_recent, consisting of + only recent entries from the table films, using a + prepared statement. The new table has OIDs and will be dropped at commit: PREPARE recentfilms(date) AS SELECT * FROM films WHERE date_prod > $1; -CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS +CREATE TEMP TABLE films_recent WITH (OIDS) ON COMMIT DROP AS EXECUTE recentfilms('2002-01-01'); @@ -280,13 +286,8 @@ CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS this is not currently implemented by PostgreSQL. The behavior provided by PostgreSQL is equivalent to the standard's WITH DATA case. - - - - - - WITH/WITHOUT OIDS is a PostgreSQL - extension. + WITH NO DATA can be simulated by appending + LIMIT 0 to the query. @@ -299,6 +300,13 @@ CREATE TEMP TABLE films_recent WITH OIDS ON COMMIT DROP AS + + + The WITH clause is a PostgreSQL + extension; neither storage parameters nor OIDs are in the standard. + + + The PostgreSQL concept of tablespaces is not diff --git a/doc/src/sgml/ref/reindex.sgml b/doc/src/sgml/ref/reindex.sgml index d589f9e82a..dbe10ca762 100644 --- a/doc/src/sgml/ref/reindex.sgml +++ b/doc/src/sgml/ref/reindex.sgml @@ -1,5 +1,5 @@ @@ -30,7 +30,7 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } nam REINDEX rebuilds an index using the data stored in the index's table, replacing the old copy of the index. There are - two main reasons to use REINDEX: + three main reasons to use REINDEX: @@ -45,15 +45,22 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } nam - The index in question contains a lot of dead index pages that - are not being reclaimed. This can occur with B-tree indexes in - PostgreSQL under certain access + An index has become bloated, that it is contains many + empty or nearly-empty pages. This can occur with B-tree indexes in + PostgreSQL under certain uncommon access patterns. REINDEX provides a way to reduce the space consumption of the index by writing a new version of the index without the dead pages. See for more information. + + + + You have altered a storage parameter (such as fillfactor) + for an index, and wish to ensure that the change has taken full effect. + + @@ -239,14 +246,6 @@ REINDEX { INDEX | TABLE | DATABASE | SYSTEM } nam Examples - - Recreate the indexes on the table my_table: - - -REINDEX TABLE my_table; - - - Rebuild a single index: @@ -255,6 +254,14 @@ REINDEX INDEX my_index; + + Rebuild all the indexes on the table my_table: + + +REINDEX TABLE my_table; + + + Rebuild all indexes in a particular database, without trusting the system indexes to be valid already: