mirror of
https://github.com/postgres/postgres.git
synced 2025-05-21 15:54:08 +03:00
509 lines
20 KiB
Plaintext
509 lines
20 KiB
Plaintext
<!-- doc/src/sgml/manage-ag.sgml -->
|
|
|
|
<chapter id="managing-databases">
|
|
<title>Managing Databases</title>
|
|
|
|
<indexterm zone="managing-databases"><primary>database</></>
|
|
|
|
<para>
|
|
Every instance of a running <productname>PostgreSQL</productname>
|
|
server manages one or more databases. Databases are therefore the
|
|
topmost hierarchical level for organizing <acronym>SQL</acronym>
|
|
objects (<quote>database objects</quote>). This chapter describes
|
|
the properties of databases, and how to create, manage, and destroy
|
|
them.
|
|
</para>
|
|
|
|
<sect1 id="manage-ag-overview">
|
|
<title>Overview</title>
|
|
|
|
<indexterm zone="manage-ag-overview">
|
|
<primary>schema</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
A database is a named collection of <acronym>SQL</acronym> objects
|
|
(<quote>database objects</quote>). Generally, every database
|
|
object (tables, functions, etc.) belongs to one and only one
|
|
database. (However there are a few system catalogs, for example
|
|
<literal>pg_database</>, that belong to a whole cluster and
|
|
are accessible from each database within the cluster.) More
|
|
accurately, a database is a collection of schemas and the schemas
|
|
contain the tables, functions, etc. So the full hierarchy is:
|
|
server, database, schema, table (or some other kind of object,
|
|
such as a function).
|
|
</para>
|
|
|
|
<para>
|
|
When connecting to the database server, a client must specify in
|
|
its connection request the name of the database it wants to connect
|
|
to. It is not possible to access more than one database per
|
|
connection. However, an application is not restricted in the number of
|
|
connections it opens to the same or other databases. Databases are
|
|
physically separated and access control is managed at the
|
|
connection level. If one <productname>PostgreSQL</> server
|
|
instance is to house projects or users that should be separate and
|
|
for the most part unaware of each other, it is therefore
|
|
recommendable to put them into separate databases. If the projects
|
|
or users are interrelated and should be able to use each other's
|
|
resources, they should be put in the same database but possibly
|
|
into separate schemas. Schemas are a purely logical structure and who can
|
|
access what is managed by the privilege system. More information about
|
|
managing schemas is in <xref linkend="ddl-schemas">.
|
|
</para>
|
|
|
|
<para>
|
|
Databases are created with the <command>CREATE DATABASE</> command
|
|
(see <xref linkend="manage-ag-createdb">) and destroyed with the
|
|
<command>DROP DATABASE</> command
|
|
(see <xref linkend="manage-ag-dropdb">).
|
|
To determine the set of existing databases, examine the
|
|
<structname>pg_database</> system catalog, for example
|
|
<synopsis>
|
|
SELECT datname FROM pg_database;
|
|
</synopsis>
|
|
The <xref linkend="app-psql"> program's <literal>\l</> meta-command
|
|
and <option>-l</> command-line option are also useful for listing the
|
|
existing databases.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The <acronym>SQL</> standard calls databases <quote>catalogs</>, but there
|
|
is no difference in practice.
|
|
</para>
|
|
</note>
|
|
</sect1>
|
|
|
|
<sect1 id="manage-ag-createdb">
|
|
<title>Creating a Database</title>
|
|
|
|
<para>
|
|
In order to create a database, the <productname>PostgreSQL</>
|
|
server must be up and running (see <xref
|
|
linkend="server-start">).
|
|
</para>
|
|
|
|
<para>
|
|
Databases are created with the SQL command
|
|
<xref linkend="sql-createdatabase">:<indexterm><primary>CREATE
|
|
DATABASE</></>
|
|
<synopsis>
|
|
CREATE DATABASE <replaceable>name</>;
|
|
</synopsis>
|
|
where <replaceable>name</> follows the usual rules for
|
|
<acronym>SQL</acronym> identifiers. The current role automatically
|
|
becomes the owner of the new database. It is the privilege of the
|
|
owner of a database to remove it later (which also removes all
|
|
the objects in it, even if they have a different owner).
|
|
</para>
|
|
|
|
<para>
|
|
The creation of databases is a restricted operation. See <xref
|
|
linkend="role-attributes"> for how to grant permission.
|
|
</para>
|
|
|
|
<para>
|
|
Since you need to be connected to the database server in order to
|
|
execute the <command>CREATE DATABASE</command> command, the
|
|
question remains how the <emphasis>first</> database at any given
|
|
site can be created. The first database is always created by the
|
|
<command>initdb</> command when the data storage area is
|
|
initialized. (See <xref linkend="creating-cluster">.) This
|
|
database is called
|
|
<literal>postgres</>.<indexterm><primary>postgres</></> So to
|
|
create the first <quote>ordinary</> database you can connect to
|
|
<literal>postgres</>.
|
|
</para>
|
|
|
|
<para>
|
|
A second database,
|
|
<literal>template1</literal>,<indexterm><primary>template1</></>
|
|
is also created during database cluster initialization. Whenever a
|
|
new database is created within the
|
|
cluster, <literal>template1</literal> is essentially cloned.
|
|
This means that any changes you make in <literal>template1</> are
|
|
propagated to all subsequently created databases. Because of this,
|
|
avoid creating objects in <literal>template1</> unless you want them
|
|
propagated to every newly created database. More details
|
|
appear in <xref linkend="manage-ag-templatedbs">.
|
|
</para>
|
|
|
|
<para>
|
|
As a convenience, there is a program you can
|
|
execute from the shell to create new databases,
|
|
<command>createdb</>.<indexterm><primary>createdb</></>
|
|
|
|
<synopsis>
|
|
createdb <replaceable class="parameter">dbname</replaceable>
|
|
</synopsis>
|
|
|
|
<command>createdb</> does no magic. It connects to the <literal>postgres</>
|
|
database and issues the <command>CREATE DATABASE</> command,
|
|
exactly as described above.
|
|
The <xref linkend="app-createdb"> reference page contains the invocation
|
|
details. Note that <command>createdb</> without any arguments will create
|
|
a database with the current user name.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
<xref linkend="client-authentication"> contains information about
|
|
how to restrict who can connect to a given database.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Sometimes you want to create a database for someone else, and have him
|
|
become the owner of the new database, so he can
|
|
configure and manage it himself. To achieve that, use one of the
|
|
following commands:
|
|
<programlisting>
|
|
CREATE DATABASE <replaceable>dbname</> OWNER <replaceable>rolename</>;
|
|
</programlisting>
|
|
from the SQL environment, or:
|
|
<programlisting>
|
|
createdb -O <replaceable>rolename</> <replaceable>dbname</>
|
|
</programlisting>
|
|
from the shell.
|
|
Only the superuser is allowed to create a database for
|
|
someone else (that is, for a role you are not a member of).
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="manage-ag-templatedbs">
|
|
<title>Template Databases</title>
|
|
|
|
<para>
|
|
<command>CREATE DATABASE</> actually works by copying an existing
|
|
database. By default, it copies the standard system database named
|
|
<literal>template1</>.<indexterm><primary>template1</></> Thus that
|
|
database is the <quote>template</> from which new databases are
|
|
made. If you add objects to <literal>template1</>, these objects
|
|
will be copied into subsequently created user databases. This
|
|
behavior allows site-local modifications to the standard set of
|
|
objects in databases. For example, if you install the procedural
|
|
language <application>PL/Perl</> in <literal>template1</>, it will
|
|
automatically be available in user databases without any extra
|
|
action being taken when those databases are created.
|
|
</para>
|
|
|
|
<para>
|
|
There is a second standard system database named
|
|
<literal>template0</>.<indexterm><primary>template0</></> This
|
|
database contains the same data as the initial contents of
|
|
<literal>template1</>, that is, only the standard objects
|
|
predefined by your version of
|
|
<productname>PostgreSQL</productname>. <literal>template0</>
|
|
should never be changed after the database cluster has been
|
|
initialized. By instructing
|
|
<command>CREATE DATABASE</> to copy <literal>template0</> instead
|
|
of <literal>template1</>, you can create a <quote>virgin</> user
|
|
database that contains none of the site-local additions in
|
|
<literal>template1</>. This is particularly handy when restoring a
|
|
<literal>pg_dump</> dump: the dump script should be restored in a
|
|
virgin database to ensure that one recreates the correct contents
|
|
of the dumped database, without conflicting with objects that
|
|
might have been added to <literal>template1</> later on.
|
|
</para>
|
|
|
|
<para>
|
|
Another common reason for copying <literal>template0</> instead
|
|
of <literal>template1</> is that new encoding and locale settings
|
|
can be specified when copying <literal>template0</>, whereas a copy
|
|
of <literal>template1</> must use the same settings it does.
|
|
This is because <literal>template1</> might contain encoding-specific
|
|
or locale-specific data, while <literal>template0</> is known not to.
|
|
</para>
|
|
|
|
<para>
|
|
To create a database by copying <literal>template0</literal>, use:
|
|
<programlisting>
|
|
CREATE DATABASE <replaceable>dbname</> TEMPLATE template0;
|
|
</programlisting>
|
|
from the SQL environment, or:
|
|
<programlisting>
|
|
createdb -T template0 <replaceable>dbname</>
|
|
</programlisting>
|
|
from the shell.
|
|
</para>
|
|
|
|
<para>
|
|
It is possible to create additional template databases, and indeed
|
|
one can copy any database in a cluster by specifying its name
|
|
as the template for <command>CREATE DATABASE</>. It is important to
|
|
understand, however, that this is not (yet) intended as
|
|
a general-purpose <quote><command>COPY DATABASE</command></quote> facility.
|
|
The principal limitation is that no other sessions can be connected to
|
|
the source database while it is being copied. <command>CREATE
|
|
DATABASE</> will fail if any other connection exists when it starts;
|
|
during the copy operation, new connections to the source database
|
|
are prevented.
|
|
</para>
|
|
|
|
<para>
|
|
Two useful flags exist in <literal>pg_database</literal><indexterm><primary>pg_database</></> for each
|
|
database: the columns <literal>datistemplate</literal> and
|
|
<literal>datallowconn</literal>. <literal>datistemplate</literal>
|
|
can be set to indicate that a database is intended as a template for
|
|
<command>CREATE DATABASE</>. If this flag is set, the database can be
|
|
cloned by any user with <literal>CREATEDB</> privileges; if it is not set,
|
|
only superusers and the owner of the database can clone it.
|
|
If <literal>datallowconn</literal> is false, then no new connections
|
|
to that database will be allowed (but existing sessions are not terminated
|
|
simply by setting the flag false). The <literal>template0</literal>
|
|
database is normally marked <literal>datallowconn = false</> to prevent its modification.
|
|
Both <literal>template0</literal> and <literal>template1</literal>
|
|
should always be marked with <literal>datistemplate = true</>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
<literal>template1</> and <literal>template0</> do not have any special
|
|
status beyond the fact that the name <literal>template1</> is the default
|
|
source database name for <command>CREATE DATABASE</>.
|
|
For example, one could drop <literal>template1</> and recreate it from
|
|
<literal>template0</> without any ill effects. This course of action
|
|
might be advisable if one has carelessly added a bunch of junk in
|
|
<literal>template1</>. (To delete <literal>template1</literal>,
|
|
it must have <literal>pg_database.datistemplate = false</>.)
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>postgres</> database is also created when a database
|
|
cluster is initialized. This database is meant as a default database for
|
|
users and applications to connect to. It is simply a copy of
|
|
<literal>template1</> and can be dropped and recreated if necessary.
|
|
</para>
|
|
</note>
|
|
</sect1>
|
|
|
|
<sect1 id="manage-ag-config">
|
|
<title>Database Configuration</title>
|
|
|
|
<para>
|
|
Recall from <xref linkend="runtime-config"> that the
|
|
<productname>PostgreSQL</> server provides a large number of
|
|
run-time configuration variables. You can set database-specific
|
|
default values for many of these settings.
|
|
</para>
|
|
|
|
<para>
|
|
For example, if for some reason you want to disable the
|
|
<acronym>GEQO</acronym> optimizer for a given database, you'd
|
|
ordinarily have to either disable it for all databases or make sure
|
|
that every connecting client is careful to issue <literal>SET geqo
|
|
TO off</literal>. To make this setting the default within a particular
|
|
database, you can execute the command:
|
|
<programlisting>
|
|
ALTER DATABASE mydb SET geqo TO off;
|
|
</programlisting>
|
|
This will save the setting (but not set it immediately). In
|
|
subsequent connections to this database it will appear as though
|
|
<literal>SET geqo TO off;</literal> had been executed just before the
|
|
session started.
|
|
Note that users can still alter this setting during their sessions; it
|
|
will only be the default. To undo any such setting, use
|
|
<literal>ALTER DATABASE <replaceable>dbname</> RESET
|
|
<replaceable>varname</></literal>.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="manage-ag-dropdb">
|
|
<title>Destroying a Database</title>
|
|
|
|
<para>
|
|
Databases are destroyed with the command
|
|
<xref linkend="sql-dropdatabase">:<indexterm><primary>DROP DATABASE</></>
|
|
<synopsis>
|
|
DROP DATABASE <replaceable>name</>;
|
|
</synopsis>
|
|
Only the owner of the database, or
|
|
a superuser, can drop a database. Dropping a database removes all objects
|
|
that were
|
|
contained within the database. The destruction of a database cannot
|
|
be undone.
|
|
</para>
|
|
|
|
<para>
|
|
You cannot execute the <command>DROP DATABASE</command> command
|
|
while connected to the victim database. You can, however, be
|
|
connected to any other database, including the <literal>template1</>
|
|
database.
|
|
<literal>template1</> would be the only option for dropping the last user database of a
|
|
given cluster.
|
|
</para>
|
|
|
|
<para>
|
|
For convenience, there is also a shell program to drop
|
|
databases, <xref linkend="app-dropdb">:<indexterm><primary>dropdb</></>
|
|
<synopsis>
|
|
dropdb <replaceable class="parameter">dbname</replaceable>
|
|
</synopsis>
|
|
(Unlike <command>createdb</>, it is not the default action to drop
|
|
the database with the current user name.)
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="manage-ag-tablespaces">
|
|
<title>Tablespaces</title>
|
|
|
|
<indexterm zone="manage-ag-tablespaces">
|
|
<primary>tablespace</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Tablespaces in <productname>PostgreSQL</> 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.
|
|
</para>
|
|
|
|
<para>
|
|
By using tablespaces, an administrator can control the disk layout
|
|
of a <productname>PostgreSQL</> 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.
|
|
</para>
|
|
|
|
<para>
|
|
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.
|
|
</para>
|
|
|
|
<para>
|
|
To define a tablespace, use the <xref
|
|
linkend="sql-createtablespace">
|
|
command, for example:<indexterm><primary>CREATE TABLESPACE</></>:
|
|
<programlisting>
|
|
CREATE TABLESPACE fastspace LOCATION '/mnt/sda1/postgresql/data';
|
|
</programlisting>
|
|
The location must be an existing, empty directory that is owned by
|
|
the <productname>PostgreSQL</> operating system user. All objects subsequently
|
|
created within the tablespace will be stored in files underneath this
|
|
directory.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
There is usually not much point in making more than one
|
|
tablespace per logical file system, since you cannot control the location
|
|
of individual files within a logical file system. However,
|
|
<productname>PostgreSQL</> does not enforce any such limitation, and
|
|
indeed it is not directly aware of the file system boundaries on your
|
|
system. It just stores files in the directories you tell it to use.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Creation of the tablespace itself must be done as a database superuser,
|
|
but after that you can allow ordinary database users to use it.
|
|
To do that, grant them the <literal>CREATE</> privilege on it.
|
|
</para>
|
|
|
|
<para>
|
|
Tables, indexes, and entire databases can be assigned to
|
|
particular tablespaces. To do so, a user with the <literal>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 <literal>space1</>:
|
|
<programlisting>
|
|
CREATE TABLE foo(i int) TABLESPACE space1;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Alternatively, use the <xref linkend="guc-default-tablespace"> parameter:
|
|
<programlisting>
|
|
SET default_tablespace = space1;
|
|
CREATE TABLE foo(i int);
|
|
</programlisting>
|
|
When <varname>default_tablespace</> is set to anything but an empty
|
|
string, it supplies an implicit <literal>TABLESPACE</> clause for
|
|
<command>CREATE TABLE</> and <command>CREATE INDEX</> commands that
|
|
do not have an explicit one.
|
|
</para>
|
|
|
|
<para>
|
|
There is also a <xref linkend="guc-temp-tablespaces"> parameter, which
|
|
determines the placement of temporary tables and indexes, as well as
|
|
temporary files that are used for purposes such as sorting large data
|
|
sets. This can be a list of tablespace names, rather than only one,
|
|
so that the load associated with temporary objects can be spread over
|
|
multiple tablespaces. A random member of the list is picked each time
|
|
a temporary object is to be created.
|
|
</para>
|
|
|
|
<para>
|
|
The tablespace associated with a database is used to store the system
|
|
catalogs of that database. Furthermore, it is the default tablespace
|
|
used for tables, indexes, and temporary files created within the database,
|
|
if no <literal>TABLESPACE</> clause is given and no other selection is
|
|
specified by <varname>default_tablespace</> or
|
|
<varname>temp_tablespaces</> (as appropriate).
|
|
If a database is created without specifying a tablespace for it,
|
|
it uses the same tablespace as the template database it is copied from.
|
|
</para>
|
|
|
|
<para>
|
|
Two tablespaces are automatically created when the database cluster
|
|
is initialized. The
|
|
<literal>pg_global</> tablespace is used for shared system catalogs. The
|
|
<literal>pg_default</> tablespace is the default tablespace of the
|
|
<literal>template1</> and <literal>template0</> databases (and, therefore,
|
|
will be the default tablespace for other databases as well, unless
|
|
overridden by a <literal>TABLESPACE</> clause in <command>CREATE
|
|
DATABASE</>).
|
|
</para>
|
|
|
|
<para>
|
|
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.
|
|
</para>
|
|
|
|
<para>
|
|
To remove an empty tablespace, use the <xref
|
|
linkend="sql-droptablespace">
|
|
command.
|
|
</para>
|
|
|
|
<para>
|
|
To determine the set of existing tablespaces, examine the
|
|
<structname>pg_tablespace</> system catalog, for example
|
|
<synopsis>
|
|
SELECT spcname FROM pg_tablespace;
|
|
</synopsis>
|
|
The <xref linkend="app-psql"> program's <literal>\db</> meta-command
|
|
is also useful for listing the existing tablespaces.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</> makes use of symbolic links
|
|
to simplify the implementation of tablespaces. This
|
|
means that tablespaces can be used <emphasis>only</> on systems
|
|
that support symbolic links.
|
|
</para>
|
|
|
|
<para>
|
|
The directory <filename>$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 server is running; and after you restart the server,
|
|
update the <structname>pg_tablespace</> catalog with the new
|
|
locations. (If you do not, <literal>pg_dump</> will continue to output
|
|
the old tablespace locations.)
|
|
</para>
|
|
|
|
</sect1>
|
|
</chapter>
|