4 pg_restore — restore a PostgreSQL database from an archive file created
9 pg_restore [connection-option...] [option...] [filename]
13 pg_restore is a utility for restoring a PostgreSQL database from an
14 archive created by pg_dump in one of the non-plain-text formats. It
15 will issue the commands necessary to reconstruct the database to the
16 state it was in at the time it was saved. The archive files also allow
17 pg_restore to be selective about what is restored, or even to reorder
18 the items prior to being restored. The archive files are designed to be
19 portable across architectures.
21 pg_restore can operate in two modes. If a database name is specified,
22 pg_restore connects to that database and restores archive contents
23 directly into the database. Otherwise, a script containing the SQL
24 commands necessary to rebuild the database is created and written to a
25 file or standard output. This script output is equivalent to the plain
26 text output format of pg_dump. Some of the options controlling the
27 output are therefore analogous to pg_dump options.
29 Obviously, pg_restore cannot restore information that is not present in
30 the archive file. For instance, if the archive was made using the “dump
31 data as INSERT commands” option, pg_restore will not be able to load
32 the data using COPY statements.
36 Restoring a dump causes the destination to execute arbitrary code of
37 the source superusers' choice. Partial dumps and partial restores do
38 not limit that. If the source superusers are not trusted, the dumped
39 SQL statements must be inspected before restoring. Non-plain-text dumps
40 can be inspected by using pg_restore's --file option. Note that the
41 client running the dump and restore need not trust the source or
42 destination superusers.
46 pg_restore accepts the following command line arguments.
49 Specifies the location of the archive file (or directory, for a
50 directory-format archive) to be restored. If not specified, the
51 standard input is used.
55 Restore only the data, not the schema (data definitions) or
56 statistics. Table data, large objects, and sequence values are
57 restored, if present in the archive.
59 This option is similar to, but for historical reasons not
60 identical to, specifying --section=data.
64 Before restoring database objects, issue commands to DROP all
65 the objects that will be restored. This option is useful for
66 overwriting an existing database. If any of the objects do not
67 exist in the destination database, ignorable error messages will
68 be reported, unless --if-exists is also specified.
72 Create the database before restoring into it. If --clean is also
73 specified, drop and recreate the target database before
76 With --create, pg_restore also restores the database's comment
77 if any, and any configuration variable settings that are
78 specific to this database, that is, any ALTER DATABASE ... SET
79 ... and ALTER ROLE ... IN DATABASE ... SET ... commands that
80 mention this database. Access privileges for the database itself
81 are also restored, unless --no-acl is specified.
83 When this option is used, the database named with -d is used
84 only to issue the initial DROP DATABASE and CREATE DATABASE
85 commands. All data is restored into the database name that
86 appears in the archive.
90 Connect to database dbname and restore directly into the
91 database. The dbname can be a connection string. If so,
92 connection string parameters will override any conflicting
97 Exit if an error is encountered while sending SQL commands to
98 the database. The default is to continue and to display a count
99 of errors at the end of the restoration.
103 Specify output file for generated script, or for the listing
104 when used with -l. Use - for stdout.
108 Specify format of the archive. It is not necessary to specify
109 the format, since pg_restore will determine the format
110 automatically. If specified, it can be one of the following:
114 The archive is in the custom format of pg_dump.
118 The archive is a directory archive.
122 The archive is a tar archive.
126 Restore definition of named index only. Multiple indexes may be
127 specified with multiple -I switches.
130 --jobs=number-of-jobs
131 Run the most time-consuming steps of pg_restore — those that
132 load data, create indexes, or create constraints — concurrently,
133 using up to number-of-jobs concurrent sessions. This option can
134 dramatically reduce the time to restore a large database to a
135 server running on a multiprocessor machine. This option is
136 ignored when emitting a script rather than connecting directly
137 to a database server.
139 Each job is one process or one thread, depending on the
140 operating system, and uses a separate connection to the server.
142 The optimal value for this option depends on the hardware setup
143 of the server, of the client, and of the network. Factors
144 include the number of CPU cores and the disk setup. A good place
145 to start is the number of CPU cores on the server, but values
146 larger than that can also lead to faster restore times in many
147 cases. Of course, values that are too high will lead to
148 decreased performance because of thrashing.
150 Only the custom and directory archive formats are supported with
151 this option. The input must be a regular file or directory (not,
152 for example, a pipe or standard input). Also, multiple jobs
153 cannot be used together with the option --single-transaction.
157 List the table of contents of the archive. The output of this
158 operation can be used as input to the -L option. Note that if
159 filtering switches such as -n or -t are used with -l, they will
160 restrict the items listed.
164 Restore only those archive elements that are listed in
165 list-file, and restore them in the order they appear in the
166 file. Note that if filtering switches such as -n or -t are used
167 with -L, they will further restrict the items restored.
169 list-file is normally created by editing the output of a
170 previous -l operation. Lines can be moved or removed, and can
171 also be commented out by placing a semicolon (;) at the start of
172 the line. See below for examples.
176 Restore only objects that are in the named schema. Multiple
177 schemas may be specified with multiple -n switches. This can be
178 combined with the -t option to restore just a specific table.
181 --exclude-schema=schema
182 Do not restore objects that are in the named schema. Multiple
183 schemas to be excluded may be specified with multiple -N
186 When both -n and -N are given for the same schema name, the -N
187 switch wins and the schema is excluded.
191 Do not output commands to set ownership of objects to match the
192 original database. By default, pg_restore issues ALTER OWNER or
193 SET SESSION AUTHORIZATION statements to set ownership of created
194 schema elements. These statements will fail unless the initial
195 connection to the database is made by a superuser (or the same
196 user that owns all of the objects in the script). With -O, any
197 user name can be used for the initial connection, and this user
198 will own all the created objects.
200 -P function-name(argtype [, ...])
201 --function=function-name(argtype [, ...])
202 Restore the named function only. Be careful to spell the
203 function name and arguments exactly as they appear in the dump
204 file's table of contents. Multiple functions may be specified
205 with multiple -P switches.
209 This option is obsolete but still accepted for backwards
214 Restore only the schema (data definitions), not data, to the
215 extent that schema entries are present in the archive.
217 This option cannot be used with --data-only or
218 --statistics-only. It is similar to, but for historical reasons
219 not identical to, specifying --section=pre-data
220 --section=post-data --no-statistics.
222 (Do not confuse this with the --schema option, which uses the
223 word “schema” in a different meaning.)
227 Specify the superuser user name to use when disabling triggers.
228 This is relevant only if --disable-triggers is used.
232 Restore definition and/or data of only the named table. For this
233 purpose, “table” includes views, materialized views, sequences,
234 and foreign tables. Multiple tables can be selected by writing
235 multiple -t switches. This option can be combined with the -n
236 option to specify table(s) in a particular schema.
240 When -t is specified, pg_restore makes no attempt to restore any
241 other database objects that the selected table(s) might depend
242 upon. Therefore, there is no guarantee that a specific-table
243 restore into a clean database will succeed.
247 This flag does not behave identically to the -t flag of pg_dump.
248 There is not currently any provision for wild-card matching in
249 pg_restore, nor can you include a schema name within its -t.
250 And, while pg_dump's -t flag will also dump subsidiary objects
251 (such as indexes) of the selected table(s), pg_restore's -t flag
252 does not include such subsidiary objects.
256 In versions prior to PostgreSQL 9.6, this flag matched only
257 tables, not any other type of relation.
261 Restore named trigger only. Multiple triggers may be specified
262 with multiple -T switches.
266 Specifies verbose mode. This will cause pg_restore to output
267 detailed object comments and start/stop times to the output
268 file, and progress messages to standard error. Repeating the
269 option causes additional debug-level messages to appear on
274 Print the pg_restore version and exit.
279 Prevent restoration of access privileges (grant/revoke
284 Execute the restore as a single transaction (that is, wrap the
285 emitted commands in BEGIN/COMMIT). This ensures that either all
286 the commands complete successfully, or no changes are applied.
287 This option implies --exit-on-error.
290 This option is relevant only when performing a restore without
291 schema. It instructs pg_restore to execute commands to
292 temporarily disable triggers on the target tables while the data
293 is restored. Use this if you have referential integrity checks
294 or other triggers on the tables that you do not want to invoke
297 Presently, the commands emitted for --disable-triggers must be
298 done as superuser. So you should also specify a superuser name
299 with -S or, preferably, run pg_restore as a PostgreSQL
302 --enable-row-security
303 This option is relevant only when restoring the contents of a
304 table which has row security. By default, pg_restore will set
305 row_security to off, to ensure that all data is restored in to
306 the table. If the user does not have sufficient privileges to
307 bypass row security, then an error is thrown. This parameter
308 instructs pg_restore to set row_security to on instead, allowing
309 the user to attempt to restore the contents of the table with
310 row security enabled. This might still fail if the user does not
311 have the right to insert the rows from the dump into the table.
313 Note that this option currently also requires the dump be in
314 INSERT format, as COPY FROM does not support row security.
317 Specify a filename from which to read patterns for objects
318 excluded or included from restore. The patterns are interpreted
319 according to the same rules as -n/--schema for including objects
320 in schemas, -N/--exclude-schema for excluding objects in
321 schemas, -P/--function for restoring named functions, -I/--index
322 for restoring named indexes, -t/--table for restoring named
323 tables or -T/--trigger for restoring triggers. To read from
324 STDIN, use - as the filename. The --filter option can be
325 specified in conjunction with the above listed options for
326 including or excluding objects, and can also be specified more
327 than once for multiple filter files.
329 The file lists one database pattern per row, with the following
332 { include | exclude } { function | index | schema | table | trigger } PATTERN
334 The first keyword specifies whether the objects matched by the
335 pattern are to be included or excluded. The second keyword
336 specifies the type of object to be filtered using the pattern:
338 + function: functions, works like the -P/--function option. This
339 keyword can only be used with the include keyword.
340 + index: indexes, works like the -I/--indexes option. This
341 keyword can only be used with the include keyword.
342 + schema: schemas, works like the -n/--schema and
343 -N/--exclude-schema options.
344 + table: tables, works like the -t/--table option. This keyword
345 can only be used with the include keyword.
346 + trigger: triggers, works like the -T/--trigger option. This
347 keyword can only be used with the include keyword.
349 Lines starting with # are considered comments and ignored.
350 Comments can be placed after an object pattern row as well.
351 Blank lines are also ignored. See Patterns for how to perform
355 Use DROP ... IF EXISTS commands to drop objects in --clean mode.
356 This suppresses “does not exist” errors that might otherwise be
357 reported. This option is not valid unless --clean is also
361 Do not output commands to restore comments, even if the archive
365 Do not output commands to restore data, even if the archive
368 --no-data-for-failed-tables
369 By default, table data is restored even if the creation command
370 for the table failed (e.g., because it already exists). With
371 this option, data for such a table is skipped. This behavior is
372 useful if the target database already contains the desired table
373 contents. For example, auxiliary tables for PostgreSQL
374 extensions such as PostGIS might already be loaded in the target
375 database; specifying this option prevents duplicate or obsolete
376 data from being loaded into them.
378 This option is effective only when restoring directly into a
379 database, not when producing SQL script output.
382 Do not output commands to restore row security policies, even if
383 the archive contains them.
386 Do not output commands to restore publications, even if the
387 archive contains them.
390 Do not output commands to restore schema (data definitions),
391 even if the archive contains them.
394 Do not output commands to restore security labels, even if the
395 archive contains them.
398 Do not output commands to restore statistics, even if the
399 archive contains them.
402 Do not output commands to restore subscriptions, even if the
403 archive contains them.
405 --no-table-access-method
406 Do not output commands to select table access methods. With this
407 option, all objects will be created with whichever table access
408 method is the default during restore.
411 Do not output commands to select tablespaces. With this option,
412 all objects will be created in whichever tablespace is the
413 default during restore.
415 --restrict-key=restrict_key
416 Use the provided string as the psql \restrict key in the dump
417 output. This can only be specified for SQL script output, i.e.,
418 when the --file option is used. If no restrict key is specified,
419 pg_restore will generate a random one as needed. Keys may
420 contain only alphanumeric characters.
422 This option is primarily intended for testing purposes and other
423 scenarios that require repeatable output (e.g., comparing dump
424 files). It is not recommended for general use, as a malicious
425 server with advance knowledge of the key may be able to inject
426 arbitrary code that will be executed on the machine that runs
427 psql with the dump output.
429 --section=sectionname
430 Only restore the named section. The section name can be
431 pre-data, data, or post-data. This option can be specified more
432 than once to select multiple sections. The default is to restore
435 The data section contains actual table data as well as
436 large-object definitions. Post-data items consist of definitions
437 of indexes, triggers, rules and constraints other than validated
438 check constraints. Pre-data items consist of all other data
442 Output commands to restore statistics, if the archive contains
443 them. This is the default.
446 Restore only the statistics, not schema (data definitions) or
450 Require that each schema (-n/--schema) and table (-t/--table)
451 qualifier match at least one schema/table in the file to be
455 Execute the restore as a series of transactions, each processing
456 up to N database objects. This option implies --exit-on-error.
458 --transaction-size offers an intermediate choice between the
459 default behavior (one transaction per SQL command) and
460 -1/--single-transaction (one transaction for all restored
461 objects). While --single-transaction has the least overhead, it
462 may be impractical for large databases because the transaction
463 will take a lock on each restored object, possibly exhausting
464 the server's lock table space. Using --transaction-size with a
465 size of a few thousand objects offers nearly the same
466 performance benefits while capping the amount of lock table
469 --use-set-session-authorization
470 Output SQL-standard SET SESSION AUTHORIZATION commands instead
471 of ALTER OWNER commands to determine object ownership. This
472 makes the dump more standards-compatible, but depending on the
473 history of the objects in the dump, might not restore properly.
477 Show help about pg_restore command line arguments, and exit.
479 pg_restore also accepts the following command line arguments for
480 connection parameters:
484 Specifies the host name of the machine on which the server is
485 running. If the value begins with a slash, it is used as the
486 directory for the Unix domain socket. The default is taken from
487 the PGHOST environment variable, if set, else a Unix domain
488 socket connection is attempted.
492 Specifies the TCP port or local Unix domain socket file
493 extension on which the server is listening for connections.
494 Defaults to the PGPORT environment variable, if set, or a
499 User name to connect as.
503 Never issue a password prompt. If the server requires password
504 authentication and a password is not available by other means
505 such as a .pgpass file, the connection attempt will fail. This
506 option can be useful in batch jobs and scripts where no user is
507 present to enter a password.
511 Force pg_restore to prompt for a password before connecting to a
514 This option is never essential, since pg_restore will
515 automatically prompt for a password if the server demands
516 password authentication. However, pg_restore will waste a
517 connection attempt finding out that the server wants a password.
518 In some cases it is worth typing -W to avoid the extra
522 Specifies a role name to be used to perform the restore. This
523 option causes pg_restore to issue a SET ROLE rolename command
524 after connecting to the database. It is useful when the
525 authenticated user (specified by -U) lacks privileges needed by
526 pg_restore, but can switch to a role with the required rights.
527 Some installations have a policy against logging in directly as
528 a superuser, and use of this option allows restores to be
529 performed without violating the policy.
537 Default connection parameters
540 Specifies whether to use color in diagnostic messages. Possible
541 values are always, auto and never.
543 This utility, like most other PostgreSQL utilities, also uses the
544 environment variables supported by libpq (see Section 32.15). However,
545 it does not read PGDATABASE when a database name is not supplied.
549 When a direct database connection is specified using the -d option,
550 pg_restore internally executes SQL statements. If you have problems
551 running pg_restore, make sure you are able to select information from
552 the database using, for example, psql. Also, any default connection
553 settings and environment variables used by the libpq front-end library
558 If your installation has any local additions to the template1 database,
559 be careful to load the output of pg_restore into a truly empty
560 database; otherwise you are likely to get errors due to duplicate
561 definitions of the added objects. To make an empty database without any
562 local additions, copy from template0 not template1, for example:
563 CREATE DATABASE foo WITH TEMPLATE template0;
565 The limitations of pg_restore are detailed below.
566 * When restoring data to a pre-existing table and the option
567 --disable-triggers is used, pg_restore emits commands to disable
568 triggers on user tables before inserting the data, then emits
569 commands to re-enable them after the data has been inserted. If the
570 restore is stopped in the middle, the system catalogs might be left
572 * pg_restore cannot restore large objects selectively; for instance,
573 only those for a specific table. If an archive contains large
574 objects, then all large objects will be restored, or none of them
575 if they are excluded via -L, -t, or other options.
577 See also the pg_dump documentation for details on limitations of
580 By default, pg_restore will restore optimizer statistics if included in
581 the dump file. If not all statistics were restored, it may be useful to
582 run ANALYZE on each restored table so the optimizer has useful
583 statistics; see Section 24.1.3 and Section 24.1.6 for more information.
587 Assume we have dumped a database called mydb into a custom-format dump
589 $ pg_dump -Fc mydb > db.dump
591 To drop the database and recreate it from the dump:
593 $ pg_restore -C -d postgres db.dump
595 The database named in the -d switch can be any database existing in the
596 cluster; pg_restore only uses it to issue the CREATE DATABASE command
597 for mydb. With -C, data is always restored into the database name that
598 appears in the dump file.
600 To restore the dump into a new database called newdb:
601 $ createdb -T template0 newdb
602 $ pg_restore -d newdb db.dump
604 Notice we don't use -C, and instead connect directly to the database to
605 be restored into. Also note that we clone the new database from
606 template0 not template1, to ensure it is initially empty.
608 To reorder database items, it is first necessary to dump the table of
609 contents of the archive:
610 $ pg_restore -l db.dump > db.list
612 The listing file consists of a header and one line for each item, e.g.:
614 ; Archive created at Mon Sep 14 13:55:39 2009
618 ; Dump Version: 1.10-0
622 ; Dumped from database version: 8.3.5
623 ; Dumped by pg_dump version: 8.3.8
626 ; Selected TOC Entries:
628 3; 2615 2200 SCHEMA - public pasha
629 1861; 0 0 COMMENT - SCHEMA public pasha
630 1862; 0 0 ACL - public pasha
631 317; 1247 17715 TYPE public composite pasha
632 319; 1247 25899 DOMAIN public domain0 pasha
634 Semicolons start a comment, and the numbers at the start of lines refer
635 to the internal archive ID assigned to each item.
637 Lines in the file can be commented out, deleted, and reordered. For
639 10; 145433 TABLE map_resolutions postgres
640 ;2; 145344 TABLE species postgres
641 ;4; 145359 TABLE nt_header postgres
642 6; 145402 TABLE species_records postgres
643 ;8; 145416 TABLE ss_old postgres
645 could be used as input to pg_restore and would only restore items 10
646 and 6, in that order:
647 $ pg_restore -L db.list db.dump
651 pg_dump, pg_dumpall, psql