Tablespaces in EnterpriseDB allow database administrators to
define locations in the file system where the files representing
database objects can be stored. Once created, a tablespace can be referred
to by name when creating database objects.
By using tablespaces, an administrator can control the disk layout
of an EnterpriseDB installation. This is useful in at
least two ways. First, if the partition or volume on which the
cluster was initialized runs out of space and cannot be extended,
a tablespace can be created on a different partition and used
until the system can be reconfigured.
Second, tablespaces allow an administrator to use knowledge of the
usage pattern of database objects to optimize performance. For
example, an index which is very heavily used can be placed on a
very fast, highly available disk, such as an expensive solid state
device. At the same time a table storing archived data which is
rarely used or not performance critical could be stored on a less
expensive, slower disk system.
To define a tablespace, use the CREATE TABLESPACE
command, for example:
CREATE TABLESPACE fastspace LOCATION '/mnt/sda1/enterprisedb/data';
The location must be an existing, empty directory that is owned by
the EnterpriseDB system user. All objects subsequently
created within the tablespace will be stored in files underneath this
directory.
Note: There is usually not much point in making more than one
tablespace per logical filesystem, since you cannot control the location
of individual files within a logical filesystem. However,
EnterpriseDB does not enforce any such limitation, and
indeed it is not directly aware of the filesystem boundaries on your
system. It just stores files in the directories you tell it to use.
Creation of the tablespace itself must be done as a database superuser,
but after that you can allow ordinary database users to make use of it.
To do that, grant them the CREATE privilege on it.
Tables, indexes, and entire databases can be assigned to
particular tablespaces. To do so, a user with the CREATE
privilege on a given tablespace must pass the tablespace name as a
parameter to the relevant command. For example, the following creates
a table in the tablespace space1:
CREATE TABLE foo(i int) TABLESPACE space1;
Alternatively, use the default_tablespace parameter:
SET default_tablespace = space1;
CREATE TABLE foo(i int);
When default_tablespace is set to anything but an empty
string, it supplies an implicit TABLESPACE clause for
CREATE TABLE and CREATE INDEX commands that
do not have an explicit one.
The tablespace associated with a database is used to store the system
catalogs of that database, as well as any temporary files created by
server processes using that database. Furthermore, it is the default
tablespace selected for tables and indexes created within the database,
if no TABLESPACE clause is given (either explicitly or via
default_tablespace) when the objects are created.
If a database is created without specifying a tablespace for it,
it uses the same tablespace as the template database it is copied from.
Two tablespaces are automatically created by initdb. The
pg_global tablespace is used for shared system catalogs. The
pg_default tablespace is the default tablespace of the
template1 and template0 databases (and, therefore,
will be the default tablespace for other databases as well, unless
overridden by a TABLESPACE clause in CREATE
DATABASE).
Once created, a tablespace can be used from any database, provided
the requesting user has sufficient privilege. This means that a tablespace
cannot be dropped until all objects in all databases using the tablespace
have been removed.
To simplify the implementation of tablespaces,
EnterpriseDB makes extensive use of symbolic links. This
means that tablespaces can be used only on systems
that support symbolic links.
The directory $PGDATA/pg_tblspc contains symbolic links that
point to each of the non-built-in tablespaces defined in the cluster.
Although not recommended, it is possible to adjust the tablespace
layout by hand by redefining these links. Two warnings: do not do so
while the edb-postmaster is running; and after you restart the edb-postmaster,
update the pg_tablespace catalog to show the new
locations. (If you do not, pg_dump will continue to show
the old tablespace locations.)