table of contents
PG_RESTORE(1) | PostgreSQL 16.4 Documentation | PG_RESTORE(1) |
NAME¶
pg_restore - restore a PostgreSQL database from an archive file created by pg_dump
SYNOPSIS¶
pg_restore [connection-option...] [option...] [filename]
DESCRIPTION¶
pg_restore is a utility for restoring a PostgreSQL database from an archive created by pg_dump(1) in one of the non-plain-text formats. It will issue the commands necessary to reconstruct the database to the state it was in at the time it was saved. The archive files also allow pg_restore to be selective about what is restored, or even to reorder the items prior to being restored. The archive files are designed to be portable across architectures.
pg_restore can operate in two modes. If a database name is specified, pg_restore connects to that database and restores archive contents directly into the database. Otherwise, a script containing the SQL commands necessary to rebuild the database is created and written to a file or standard output. This script output is equivalent to the plain text output format of pg_dump. Some of the options controlling the output are therefore analogous to pg_dump options.
Obviously, pg_restore cannot restore information that is not present in the archive file. For instance, if the archive was made using the “dump data as INSERT commands” option, pg_restore will not be able to load the data using COPY statements.
OPTIONS¶
pg_restore accepts the following command line arguments.
filename
-a
--data-only
This option is similar to, but for historical reasons not identical to, specifying --section=data.
-c
--clean
-C
--create
With --create, pg_restore also restores the database's comment if any, and any configuration variable settings that are specific to this database, that is, any ALTER DATABASE ... SET ... and ALTER ROLE ... IN DATABASE ... SET ... commands that mention this database. Access privileges for the database itself are also restored, unless --no-acl is specified.
When this option is used, the database named with -d is used only to issue the initial DROP DATABASE and CREATE DATABASE commands. All data is restored into the database name that appears in the archive.
-d dbname
--dbname=dbname
-e
--exit-on-error
-f filename
--file=filename
-F format
--format=format
c
custom
d
directory
t
tar
-I index
--index=index
-j number-of-jobs
--jobs=number-of-jobs
Each job is one process or one thread, depending on the operating system, and uses a separate connection to the server.
The optimal value for this option depends on the hardware setup of the server, of the client, and of the network. Factors include the number of CPU cores and the disk setup. A good place to start is the number of CPU cores on the server, but values larger than that can also lead to faster restore times in many cases. Of course, values that are too high will lead to decreased performance because of thrashing.
Only the custom and directory archive formats are supported with this option. The input must be a regular file or directory (not, for example, a pipe or standard input). Also, multiple jobs cannot be used together with the option --single-transaction.
-l
--list
-L list-file
--use-list=list-file
list-file is normally created by editing the output of a previous -l operation. Lines can be moved or removed, and can also be commented out by placing a semicolon (;) at the start of the line. See below for examples.
-n schema
--schema=schema
-N schema
--exclude-schema=schema
When both -n and -N are given for the same schema name, the -N switch wins and the schema is excluded.
-O
--no-owner
-P function-name(argtype [, ...])
--function=function-name(argtype [, ...])
-R
--no-reconnect
-s
--schema-only
This option is the inverse of --data-only. It is similar to, but for historical reasons not identical to, specifying --section=pre-data --section=post-data.
(Do not confuse this with the --schema option, which uses the word “schema” in a different meaning.)
-S username
--superuser=username
-t table
--table=table
Note
When -t is specified, pg_restore makes no attempt to restore any other database objects that the selected table(s) might depend upon. Therefore, there is no guarantee that a specific-table restore into a clean database will succeed.
Note
This flag does not behave identically to the -t flag of pg_dump. There is not currently any provision for wild-card matching in pg_restore, nor can you include a schema name within its -t. And, while pg_dump's -t flag will also dump subsidiary objects (such as indexes) of the selected table(s), pg_restore's -t flag does not include such subsidiary objects.
Note
In versions prior to PostgreSQL 9.6, this flag matched only tables, not any other type of relation.
-T trigger
--trigger=trigger
-v
--verbose
-V
--version
-x
--no-privileges
--no-acl
-1
--single-transaction
--disable-triggers
Presently, the commands emitted for --disable-triggers must be done as superuser. So you should also specify a superuser name with -S or, preferably, run pg_restore as a PostgreSQL superuser.
--enable-row-security
Note that this option currently also requires the dump be in INSERT format, as COPY FROM does not support row security.
--if-exists
--no-comments
--no-data-for-failed-tables
This option is effective only when restoring directly into a database, not when producing SQL script output.
--no-publications
--no-security-labels
--no-subscriptions
--no-table-access-method
--no-tablespaces
--section=sectionname
The data section contains actual table data as well as large-object definitions. Post-data items consist of definitions of indexes, triggers, rules and constraints other than validated check constraints. Pre-data items consist of all other data definition items.
--strict-names
--use-set-session-authorization
-?
--help
pg_restore also accepts the following command line arguments for connection parameters:
-h host
--host=host
-p port
--port=port
-U username
--username=username
-w
--no-password
-W
--password
This option is never essential, since pg_restore will automatically prompt for a password if the server demands password authentication. However, pg_restore will waste a connection attempt finding out that the server wants a password. In some cases it is worth typing -W to avoid the extra connection attempt.
--role=rolename
ENVIRONMENT¶
PGHOST
PGOPTIONS
PGPORT
PGUSER
PG_COLOR
This utility, like most other PostgreSQL utilities, also uses the environment variables supported by libpq (see Section 34.15). However, it does not read PGDATABASE when a database name is not supplied.
DIAGNOSTICS¶
When a direct database connection is specified using the -d option, pg_restore internally executes SQL statements. If you have problems running pg_restore, make sure you are able to select information from the database using, for example, psql(1). Also, any default connection settings and environment variables used by the libpq front-end library will apply.
NOTES¶
If your installation has any local additions to the template1 database, be careful to load the output of pg_restore into a truly empty database; otherwise you are likely to get errors due to duplicate definitions of the added objects. To make an empty database without any local additions, copy from template0 not template1, for example:
CREATE DATABASE foo WITH TEMPLATE template0;
The limitations of pg_restore are detailed below.
See also the pg_dump(1) documentation for details on limitations of pg_dump.
Once restored, it is wise to run ANALYZE on each restored table so the optimizer has useful statistics; see Section 25.1.3 and Section 25.1.6 for more information.
EXAMPLES¶
Assume we have dumped a database called mydb into a custom-format dump file:
$ pg_dump -Fc mydb > db.dump
To drop the database and recreate it from the dump:
$ dropdb mydb $ pg_restore -C -d postgres db.dump
The database named in the -d switch can be any database existing in the cluster; pg_restore only uses it to issue the CREATE DATABASE command for mydb. With -C, data is always restored into the database name that appears in the dump file.
To restore the dump into a new database called newdb:
$ createdb -T template0 newdb $ pg_restore -d newdb db.dump
Notice we don't use -C, and instead connect directly to the database to be restored into. Also note that we clone the new database from template0 not template1, to ensure it is initially empty.
To reorder database items, it is first necessary to dump the table of contents of the archive:
$ pg_restore -l db.dump > db.list
The listing file consists of a header and one line for each item, e.g.:
; ; Archive created at Mon Sep 14 13:55:39 2009 ; dbname: DBDEMOS ; TOC Entries: 81 ; Compression: 9 ; Dump Version: 1.10-0 ; Format: CUSTOM ; Integer: 4 bytes ; Offset: 8 bytes ; Dumped from database version: 8.3.5 ; Dumped by pg_dump version: 8.3.8 ; ; ; Selected TOC Entries: ; 3; 2615 2200 SCHEMA - public pasha 1861; 0 0 COMMENT - SCHEMA public pasha 1862; 0 0 ACL - public pasha 317; 1247 17715 TYPE public composite pasha 319; 1247 25899 DOMAIN public domain0 pasha
Semicolons start a comment, and the numbers at the start of lines refer to the internal archive ID assigned to each item.
Lines in the file can be commented out, deleted, and reordered. For example:
10; 145433 TABLE map_resolutions postgres ;2; 145344 TABLE species postgres ;4; 145359 TABLE nt_header postgres 6; 145402 TABLE species_records postgres ;8; 145416 TABLE ss_old postgres
could be used as input to pg_restore and would only restore items 10 and 6, in that order:
$ pg_restore -L db.list db.dump
SEE ALSO¶
2024 | PostgreSQL 16.4 |