3 <chapter id=
"managing-databases">
4 <title>Managing Databases
</title>
6 <indexterm zone=
"managing-databases"><primary>database<
/><
/>
9 Every instance of a running
<productname>PostgreSQL
</productname>
10 server manages one or more databases. Databases are therefore the
11 topmost hierarchical level for organizing
<acronym>SQL
</acronym>
12 objects (
<quote>database objects
</quote>). This chapter describes
13 the properties of databases, and how to create, manage, and destroy
17 <sect1 id=
"manage-ag-overview">
18 <title>Overview
</title>
20 <indexterm zone=
"manage-ag-overview">
21 <primary>schema
</primary>
25 A database is a named collection of
<acronym>SQL
</acronym> objects
26 (
<quote>database objects
</quote>). Generally, every database
27 object (tables, functions, etc.) belongs to one and only one
28 database. (But there are a few system catalogs, for example
29 <literal>pg_database<
/>, that belong to a whole cluster and
30 are accessible from each database within the cluster.) More
31 accurately, a database is a collection of schemas and the schemas
32 contain the tables, functions, etc. So the full hierarchy is:
33 server, database, schema, table (or some other kind of object,
38 When connecting to the database server, a client must specify in
39 its connection request the name of the database it wants to connect
40 to. It is not possible to access more than one database per
41 connection. (But an application is not restricted in the number of
42 connections it opens to the same or other databases.) Databases are
43 physically separated and access control is managed at the
44 connection level. If one
<productname>PostgreSQL<
/> server
45 instance is to house projects or users that should be separate and
46 for the most part unaware of each other, it is therefore
47 recommendable to put them into separate databases. If the projects
48 or users are interrelated and should be able to use each other's
49 resources they should be put in the same database, but possibly
50 into separate schemas. Schemas are a purely logical structure and who can
51 access what is managed by the privilege system. More information about
52 managing schemas is in
<xref linkend=
"ddl-schemas">.
56 Databases are created with the
<command>CREATE DATABASE<
/> command
57 (see
<xref linkend=
"manage-ag-createdb">) and destroyed with the
58 <command>DROP DATABASE<
/> command
59 (see
<xref linkend=
"manage-ag-dropdb">).
60 To determine the set of existing databases, examine the
61 <structname>pg_database<
/> system catalog, for example
63 SELECT datname FROM pg_database;
65 The
<xref linkend=
"app-psql"> program's
<literal>\l<
/> meta-command
66 and
<option>-l<
/> command-line option are also useful for listing the
72 The
<acronym>SQL<
/> standard calls databases
<quote>catalogs<
/>, but there
73 is no difference in practice.
78 <sect1 id=
"manage-ag-createdb">
79 <title>Creating a Database
</title>
82 In order to create a database, the
<productname>PostgreSQL<
/>
83 server must be up and running (see
<xref
84 linkend=
"server-start">).
88 Databases are created with the SQL command
89 <xref linkend=
"sql-createdatabase" endterm=
"sql-createdatabase-title">:
<indexterm><primary>CREATE
92 CREATE DATABASE
<replaceable>name<
/>;
94 where
<replaceable>name<
/> follows the usual rules for
95 <acronym>SQL
</acronym> identifiers. The current role automatically
96 becomes the owner of the new database. It is the privilege of the
97 owner of a database to remove it later on (which also removes all
98 the objects in it, even if they have a different owner).
102 The creation of databases is a restricted operation. See
<xref
103 linkend=
"role-attributes"> for how to grant permission.
107 Since you need to be connected to the database server in order to
108 execute the
<command>CREATE DATABASE
</command> command, the
109 question remains how the
<emphasis>first<
/> database at any given
110 site can be created. The first database is always created by the
111 <command>initdb<
/> command when the data storage area is
112 initialized. (See
<xref linkend=
"creating-cluster">.) This
114 <literal>postgres<
/>.
<indexterm><primary>postgres<
/><
/> So to
115 create the first
<quote>ordinary<
/> database you can connect to
116 <literal>postgres<
/>.
121 <literal>template1
</literal>,
<indexterm><primary>template1<
/><
/>
123 <command>initdb<
/>. Whenever a new database is created within the
124 cluster,
<literal>template1
</literal> is essentially cloned.
125 This means that any changes you make in
<literal>template1<
/> are
126 propagated to all subsequently created databases. Therefore it is
127 unwise to use
<literal>template1<
/> for real work, but when
128 used judiciously this feature can be convenient. More details
129 appear in
<xref linkend=
"manage-ag-templatedbs">.
133 As a convenience, there is a program that you can
134 execute from the shell to create new databases,
135 <command>createdb<
/>.
<indexterm><primary>createdb<
/><
/>
138 createdb
<replaceable class=
"parameter">dbname
</replaceable>
141 <command>createdb<
/> does no magic. It connects to the
<literal>postgres<
/>
142 database and issues the
<command>CREATE DATABASE<
/> command,
143 exactly as described above.
144 The
<xref linkend=
"app-createdb"> reference page contains the invocation
145 details. Note that
<command>createdb<
/> without any arguments will create
146 a database with the current user name, which might or might not be what
152 <xref linkend=
"client-authentication"> contains information about
153 how to restrict who can connect to a given database.
158 Sometimes you want to create a database for someone else. That
159 role should become the owner of the new database, so he can
160 configure and manage it himself. To achieve that, use one of the
163 CREATE DATABASE
<replaceable>dbname<
/> OWNER
<replaceable>rolename<
/>;
165 from the SQL environment, or:
167 createdb -O
<replaceable>rolename<
/> <replaceable>dbname<
/>
170 You must be a superuser to be allowed to create a database for
171 someone else (that is, for a role you are not a member of).
175 <sect1 id=
"manage-ag-templatedbs">
176 <title>Template Databases
</title>
179 <command>CREATE DATABASE<
/> actually works by copying an existing
180 database. By default, it copies the standard system database named
181 <literal>template1<
/>.
<indexterm><primary>template1<
/><
/> Thus that
182 database is the
<quote>template<
/> from which new databases are
183 made. If you add objects to
<literal>template1<
/>, these objects
184 will be copied into subsequently created user databases. This
185 behavior allows site-local modifications to the standard set of
186 objects in databases. For example, if you install the procedural
187 language
<application>PL/pgSQL<
/> in
<literal>template1<
/>, it will
188 automatically be available in user databases without any extra
189 action being taken when those databases are made.
193 There is a second standard system database named
194 <literal>template0<
/>.
<indexterm><primary>template0<
/><
/> This
195 database contains the same data as the initial contents of
196 <literal>template1<
/>, that is, only the standard objects
197 predefined by your version of
198 <productname>PostgreSQL
</productname>.
<literal>template0<
/>
199 should never be changed after
<command>initdb<
/>. By instructing
200 <command>CREATE DATABASE<
/> to copy
<literal>template0<
/> instead
201 of
<literal>template1<
/>, you can create a
<quote>virgin<
/> user
202 database that contains none of the site-local additions in
203 <literal>template1<
/>. This is particularly handy when restoring a
204 <literal>pg_dump<
/> dump: the dump script should be restored in a
205 virgin database to ensure that one recreates the correct contents
206 of the dumped database, without any conflicts with objects that
207 might have been added to
<literal>template1<
/> later on.
211 Another common reason for copying
<literal>template0<
/> instead
212 of
<literal>template1<
/> is that new encoding and locale settings
213 can be specified when copying
<literal>template0<
/>, whereas a copy
214 of
<literal>template1<
/> must use the same settings it does.
215 This is because
<literal>template1<
/> might contain encoding-specific
216 or locale-specific data, while
<literal>template0<
/> is known not to.
220 To create a database by copying
<literal>template0
</literal>, use:
222 CREATE DATABASE
<replaceable>dbname<
/> TEMPLATE template0;
224 from the SQL environment, or:
226 createdb -T template0
<replaceable>dbname<
/>
232 It is possible to create additional template databases, and indeed
233 one can copy any database in a cluster by specifying its name
234 as the template for
<command>CREATE DATABASE<
/>. It is important to
235 understand, however, that this is not (yet) intended as
236 a general-purpose
<quote><command>COPY DATABASE
</command></quote> facility.
237 The principal limitation is that no other sessions can be connected to
238 the source database while it is being copied.
<command>CREATE
239 DATABASE<
/> will fail if any other connection exists when it starts;
240 otherwise, new connections to the source database are locked out
241 until
<command>CREATE DATABASE<
/> completes.
245 Two useful flags exist in
<literal>pg_database
</literal><indexterm><primary>pg_database<
/><
/> for each
246 database: the columns
<literal>datistemplate
</literal> and
247 <literal>datallowconn
</literal>.
<literal>datistemplate
</literal>
248 can be set to indicate that a database is intended as a template for
249 <command>CREATE DATABASE<
/>. If this flag is set, the database can be
250 cloned by any user with
<literal>CREATEDB<
/> privileges; if it is not set,
251 only superusers and the owner of the database can clone it.
252 If
<literal>datallowconn
</literal> is false, then no new connections
253 to that database will be allowed (but existing sessions are not killed
254 simply by setting the flag false). The
<literal>template0
</literal>
255 database is normally marked
<literal>datallowconn = false<
/> to prevent modification of it.
256 Both
<literal>template0
</literal> and
<literal>template1
</literal>
257 should always be marked with
<literal>datistemplate = true<
/>.
262 <literal>template1<
/> and
<literal>template0<
/> do not have any special
263 status beyond the fact that the name
<literal>template1<
/> is the default
264 source database name for
<command>CREATE DATABASE<
/>.
265 For example, one could drop
<literal>template1<
/> and recreate it from
266 <literal>template0<
/> without any ill effects. This course of action
267 might be advisable if one has carelessly added a bunch of junk in
268 <literal>template1<
/>. (To delete
<literal>template1
</literal>,
269 it must have
<literal>pg_database.datistemplate = false<
/>.)
273 The
<literal>postgres<
/> database is also created when a database
274 cluster is initialized. This database is meant as a default database for
275 users and applications to connect to. It is simply a copy of
276 <literal>template1<
/> and can be dropped and recreated if required.
281 <sect1 id=
"manage-ag-config">
282 <title>Database Configuration
</title>
285 Recall from
<xref linkend=
"runtime-config"> that the
286 <productname>PostgreSQL<
/> server provides a large number of
287 run-time configuration variables. You can set database-specific
288 default values for many of these settings.
292 For example, if for some reason you want to disable the
293 <acronym>GEQO
</acronym> optimizer for a given database, you'd
294 ordinarily have to either disable it for all databases or make sure
295 that every connecting client is careful to issue
<literal>SET geqo
296 TO off;
</literal>. To make this setting the default within a particular
297 database, you can execute the command:
299 ALTER DATABASE mydb SET geqo TO off;
301 This will save the setting (but not set it immediately). In
302 subsequent connections to this database it will appear as though
303 <literal>SET geqo TO off;
</literal> had been executed just before the
305 Note that users can still alter this setting during their sessions; it
306 will only be the default. To undo any such setting, use
307 <literal>ALTER DATABASE
<replaceable>dbname<
/> RESET
308 <replaceable>varname<
/>;
</literal>.
312 <sect1 id=
"manage-ag-dropdb">
313 <title>Destroying a Database
</title>
316 Databases are destroyed with the command
317 <xref linkend=
"sql-dropdatabase" endterm=
"sql-dropdatabase-title">:
<indexterm><primary>DROP DATABASE<
/><
/>
319 DROP DATABASE
<replaceable>name<
/>;
321 Only the owner of the database, or
322 a superuser, can drop a database. Dropping a database removes all objects
324 contained within the database. The destruction of a database cannot
329 You cannot execute the
<command>DROP DATABASE
</command> command
330 while connected to the victim database. You can, however, be
331 connected to any other database, including the
<literal>template1<
/>
333 <literal>template1<
/> would be the only option for dropping the last user database of a
338 For convenience, there is also a shell program to drop
339 databases,
<xref linkend=
"app-dropdb">:
<indexterm><primary>dropdb<
/><
/>
341 dropdb
<replaceable class=
"parameter">dbname
</replaceable>
343 (Unlike
<command>createdb<
/>, it is not the default action to drop
344 the database with the current user name.)
348 <sect1 id=
"manage-ag-tablespaces">
349 <title>Tablespaces
</title>
351 <indexterm zone=
"manage-ag-tablespaces">
352 <primary>tablespace
</primary>
356 Tablespaces in
<productname>PostgreSQL<
/> allow database administrators to
357 define locations in the file system where the files representing
358 database objects can be stored. Once created, a tablespace can be referred
359 to by name when creating database objects.
363 By using tablespaces, an administrator can control the disk layout
364 of a
<productname>PostgreSQL<
/> installation. This is useful in at
365 least two ways. First, if the partition or volume on which the
366 cluster was initialized runs out of space and cannot be extended,
367 a tablespace can be created on a different partition and used
368 until the system can be reconfigured.
372 Second, tablespaces allow an administrator to use knowledge of the
373 usage pattern of database objects to optimize performance. For
374 example, an index which is very heavily used can be placed on a
375 very fast, highly available disk, such as an expensive solid state
376 device. At the same time a table storing archived data which is
377 rarely used or not performance critical could be stored on a less
378 expensive, slower disk system.
382 To define a tablespace, use the
<xref
383 linkend=
"sql-createtablespace" endterm=
"sql-createtablespace-title">
384 command, for example:
<indexterm><primary>CREATE TABLESPACE<
/><
/>:
386 CREATE TABLESPACE fastspace LOCATION '/mnt/sda1/postgresql/data';
388 The location must be an existing, empty directory that is owned by
389 the
<productname>PostgreSQL<
/> system user. All objects subsequently
390 created within the tablespace will be stored in files underneath this
396 There is usually not much point in making more than one
397 tablespace per logical file system, since you cannot control the location
398 of individual files within a logical file system. However,
399 <productname>PostgreSQL<
/> does not enforce any such limitation, and
400 indeed it is not directly aware of the file system boundaries on your
401 system. It just stores files in the directories you tell it to use.
406 Creation of the tablespace itself must be done as a database superuser,
407 but after that you can allow ordinary database users to make use of it.
408 To do that, grant them the
<literal>CREATE<
/> privilege on it.
412 Tables, indexes, and entire databases can be assigned to
413 particular tablespaces. To do so, a user with the
<literal>CREATE<
/>
414 privilege on a given tablespace must pass the tablespace name as a
415 parameter to the relevant command. For example, the following creates
416 a table in the tablespace
<literal>space1<
/>:
418 CREATE TABLE foo(i int) TABLESPACE space1;
423 Alternatively, use the
<xref linkend=
"guc-default-tablespace"> parameter:
425 SET default_tablespace = space1;
426 CREATE TABLE foo(i int);
428 When
<varname>default_tablespace<
/> is set to anything but an empty
429 string, it supplies an implicit
<literal>TABLESPACE<
/> clause for
430 <command>CREATE TABLE<
/> and
<command>CREATE INDEX<
/> commands that
431 do not have an explicit one.
435 There is also a
<xref linkend=
"guc-temp-tablespaces"> parameter, which
436 determines the placement of temporary tables and indexes, as well as
437 temporary files that are used for purposes such as sorting large data
438 sets. This can be a list of tablespace names, rather than only one,
439 so that the load associated with temporary objects can be spread over
440 multiple tablespaces. A random member of the list is picked each time
441 a temporary object is to be created.
445 The tablespace associated with a database is used to store the system
446 catalogs of that database. Furthermore, it is the default tablespace
447 used for tables, indexes, and temporary files created within the database,
448 if no
<literal>TABLESPACE<
/> clause is given and no other selection is
449 specified by
<varname>default_tablespace<
/> or
450 <varname>temp_tablespaces<
/> (as appropriate).
451 If a database is created without specifying a tablespace for it,
452 it uses the same tablespace as the template database it is copied from.
456 Two tablespaces are automatically created by
<literal>initdb<
/>. The
457 <literal>pg_global<
/> tablespace is used for shared system catalogs. The
458 <literal>pg_default<
/> tablespace is the default tablespace of the
459 <literal>template1<
/> and
<literal>template0<
/> databases (and, therefore,
460 will be the default tablespace for other databases as well, unless
461 overridden by a
<literal>TABLESPACE<
/> clause in
<command>CREATE
466 Once created, a tablespace can be used from any database, provided
467 the requesting user has sufficient privilege. This means that a tablespace
468 cannot be dropped until all objects in all databases using the tablespace
473 To remove an empty tablespace, use the
<xref
474 linkend=
"sql-droptablespace" endterm=
"sql-droptablespace-title">
479 To determine the set of existing tablespaces, examine the
480 <structname>pg_tablespace<
/> system catalog, for example
482 SELECT spcname FROM pg_tablespace;
484 The
<xref linkend=
"app-psql"> program's
<literal>\db<
/> meta-command
485 is also useful for listing the existing tablespaces.
489 <productname>PostgreSQL<
/> makes use of symbolic links
490 to simplify the implementation of tablespaces. This
491 means that tablespaces can be used
<emphasis>only<
/> on systems
492 that support symbolic links.
496 The directory
<filename>$PGDATA/pg_tblspc<
/> contains symbolic links that
497 point to each of the non-built-in tablespaces defined in the cluster.
498 Although not recommended, it is possible to adjust the tablespace
499 layout by hand by redefining these links. Two warnings: do not do so
500 while the server is running; and after you restart the server,
501 update the
<structname>pg_tablespace<
/> catalog to show the new
502 locations. (If you do not,
<literal>pg_dump<
/> will continue to show
503 the old tablespace locations.)